SQL/JSON: JSON_TABLE

Started by Nikita Glukhovabout 8 years ago101 messages
#1Nikita Glukhov
n.gluhov@postgrespro.ru
2 attachment(s)

Attached patches implementing JSON_TABLE.

This patchset depends on the 8th version of SQL/JSON functions patchset
that was posted in
/messages/by-id/cd0bb935-0158-78a7-08b5-904886deac4b@postgrespro.ru

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0012-json_table-v08.patchtext/x-patch; name=0012-json_table-v08.patchDownload
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 89e66de..fa8037f 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2923,9 +2923,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 79e6985..8a3925b 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -2839,7 +2839,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 98a93fd..8ec116e 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2184,6 +2184,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index c562447..bddb51a 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4044,7 +4044,7 @@ ExecEvalAggOrderedTransTuple(ExprState *state, ExprEvalStep *op,
 /*
  * Evaluate a expression substituting specified value in its CaseTestExpr nodes.
  */
-static Datum
+Datum
 ExecEvalExprPassingCaseValue(ExprState *estate, ExprContext *econtext,
 							 bool *isnull,
 							 Datum caseval_datum, bool caseval_isnull)
@@ -4104,6 +4104,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4165,8 +4166,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4354,6 +4361,11 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			*resnull = false;
 			break;
 
+		case IS_JSON_TABLE:
+			res = item;
+			*resnull = false;
+			break;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d",
 				 jexpr->op);
@@ -4374,6 +4386,7 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 	}
 
 	if (jexpr->op != IS_JSON_EXISTS &&
+		jexpr->op != IS_JSON_TABLE &&
 		(!empty ? jexpr->op != IS_JSON_VALUE :
 		 /* result is already coerced in DEFAULT behavior case */
 		 jexpr->on_empty.btype != JSON_BEHAVIOR_DEFAULT))
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 3b60976..fd095d9 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -167,8 +168,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	ExecAssignResultTypeFromTL(&scanstate->ss.ps);
 	ExecAssignScanProjectionInfo(&scanstate->ss);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -371,14 +373,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index d5e681d..42db8c9 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1228,6 +1228,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1238,7 +1239,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2445,6 +2448,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typename);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5380,6 +5476,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 9f69629..632fea6 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3284,6 +3310,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ebc41ea..334cabe 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -661,6 +661,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 79cb602..76af07d 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2280,6 +2280,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3147,6 +3149,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3968,6 +3971,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typename, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 5e8d253..c57e8bb 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1048,6 +1048,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1058,7 +1059,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1799,6 +1802,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4359,6 +4385,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index f50a53e..c8b31d6 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -474,6 +474,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -484,7 +485,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1398,6 +1401,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2811,6 +2841,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c49181d..de8524e 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -610,9 +610,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -621,9 +641,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -637,6 +661,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -644,6 +669,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -715,7 +742,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -725,14 +752,14 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
 	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OUT_P OUTER_P OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -821,7 +848,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -846,6 +873,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11904,6 +11935,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12407,6 +12451,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14819,6 +14865,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14930,6 +14980,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typename = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typename = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15694,6 +15973,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15721,6 +16001,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15876,6 +16158,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 9fbcfd4..bcba44d 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -43,10 +43,21 @@
 #include "parser/parse_target.h"
 #include "parser/parse_type.h"
 #include "rewrite/rewriteManip.h"
+#include "utils/builtins.h"
 #include "utils/guc.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -96,6 +107,10 @@ static List *addTargetToGroupList(ParseState *pstate, TargetEntry *tle,
 static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -753,6 +768,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1042,6 +1059,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1073,6 +1102,633 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typename = jtc->typename;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE jsoin type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan =
+				plan->plan_type == JSTP_JOINED ? plan->plan1 : plan;
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			childPlan = plan->plan2;
+		}
+		else
+			childPlan = NULL;
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1204,6 +1860,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 9d54ca4..8ee7d4f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4406,7 +4406,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4452,14 +4452,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4713,6 +4712,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 2625da5..95d9a75 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1662,7 +1662,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index c8db814..fe8e4a9 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1930,6 +1930,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 1c3eae4..f429be2 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,12 +15,16 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -44,6 +48,57 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -57,6 +112,12 @@ static inline JsonPathExecResult recursiveExecuteUnwrap(JsonPathExecContext *cxt
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -2723,3 +2784,419 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr *expr = lfirst(lc);
+
+		cxt->colexprs[i++].expr = ExecInitExpr(expr, ps);
+	}
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (!DatumGetPointer(scan->current)) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExprPassingCaseValue(estate, econtext, isnull,
+											  scan->current, false);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 26b0933..934c013 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -465,6 +465,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8864,6 +8866,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -9897,16 +9902,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10010,6 +10013,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index a5e0853..e87955d 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -785,6 +785,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							JsonReturning *returning,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index ebc4036..577d3fa 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -194,6 +194,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -483,6 +485,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 194211b..d527910 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1423,6 +1423,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1493,6 +1505,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typename;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4bfa016..19745dc 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,12 +73,19 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  */
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace uri */
 	List	   *ns_names;		/* list of namespace names */
 	Node	   *docexpr;		/* input document expression */
@@ -89,7 +96,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1182,7 +1191,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1335,6 +1345,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 74be6ae..5955218 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -231,6 +231,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -271,6 +272,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -313,7 +315,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 4e24bd1..8430866 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -262,6 +263,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -292,4 +294,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 0deee40..54959cf 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -991,6 +991,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  ?column? 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 34b70be..a204632 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -868,6 +868,935 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@.[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  ?column? 
@@ -903,3 +1832,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 084c7b1..94ecf76 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -290,6 +290,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index bdb0f41..2b2ad6a 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -265,6 +265,568 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@.[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -273,3 +835,5 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
0013-json_table-json-v08.patchtext/x-patch; name=0013-json_table-json-v08.patchDownload
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index fd095d9..e59b8ee 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -170,7 +172,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8ee7d4f..a325ad7 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4720,12 +4720,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 8430866..c3c5316 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -294,6 +294,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 54959cf..10d9c57 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -992,10 +992,961 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@.[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  ?column? 
@@ -1031,3 +1982,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 94ecf76..e5f683c 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -292,7 +292,576 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@.[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -302,3 +871,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
#2Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#1)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 9th version of JSON_TABLE patches rebased onto the latest master.

Documentation drafts written by Oleg Bartunov:
https://github.com/obartunov/sqljsondoc

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0011-json_table-v09.patchtext/x-patch; name=0011-json_table-v09.patchDownload
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 89e66de..fa8037f 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2923,9 +2923,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 900fa74..2f0d440 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -2842,7 +2842,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 7195aae..5ba8b3f 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2184,6 +2184,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index c562447..bddb51a 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4044,7 +4044,7 @@ ExecEvalAggOrderedTransTuple(ExprState *state, ExprEvalStep *op,
 /*
  * Evaluate a expression substituting specified value in its CaseTestExpr nodes.
  */
-static Datum
+Datum
 ExecEvalExprPassingCaseValue(ExprState *estate, ExprContext *econtext,
 							 bool *isnull,
 							 Datum caseval_datum, bool caseval_isnull)
@@ -4104,6 +4104,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4165,8 +4166,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4354,6 +4361,11 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			*resnull = false;
 			break;
 
+		case IS_JSON_TABLE:
+			res = item;
+			*resnull = false;
+			break;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d",
 				 jexpr->op);
@@ -4374,6 +4386,7 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 	}
 
 	if (jexpr->op != IS_JSON_EXISTS &&
+		jexpr->op != IS_JSON_TABLE &&
 		(!empty ? jexpr->op != IS_JSON_VALUE :
 		 /* result is already coerced in DEFAULT behavior case */
 		 jexpr->on_empty.btype != JSON_BEHAVIOR_DEFAULT))
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 3b60976..fd095d9 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -167,8 +168,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	ExecAssignResultTypeFromTL(&scanstate->ss.ps);
 	ExecAssignScanProjectionInfo(&scanstate->ss);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -371,14 +373,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 60a2486..3b0a43e 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1234,6 +1234,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1244,7 +1245,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2451,6 +2454,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typename);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5393,6 +5489,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 1f8a75f..a1e1e67 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3291,6 +3317,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ebc41ea..334cabe 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -661,6 +661,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 79cb602..76af07d 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2280,6 +2280,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3147,6 +3149,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3968,6 +3971,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typename, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 9ac2b24..c40c855 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1054,6 +1054,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1064,7 +1065,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1805,6 +1808,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4374,6 +4400,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 620c878..2f787f2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -479,6 +479,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -489,7 +490,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1403,6 +1406,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2822,6 +2852,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 8b212b5..6c3bc3d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -611,9 +611,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -622,9 +642,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -638,6 +662,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -645,6 +670,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -716,7 +743,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -726,7 +753,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -734,7 +761,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -825,7 +852,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -850,6 +877,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11935,6 +11966,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12438,6 +12482,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14852,6 +14898,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14963,6 +15013,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typename = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typename = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15728,6 +16007,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15756,6 +16036,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15912,6 +16194,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 3a02307..ebecf66 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -760,6 +774,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1049,6 +1065,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1080,6 +1108,633 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typename = jtc->typename;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE jsoin type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan =
+				plan->plan_type == JSTP_JOINED ? plan->plan1 : plan;
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			childPlan = plan->plan2;
+		}
+		else
+			childPlan = NULL;
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1211,6 +1866,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 2ea7cff..7d19881 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4411,7 +4411,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4457,14 +4457,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4718,6 +4717,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 053ae02..8ccb34a 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1662,7 +1662,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 112c776..8678a72 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1930,6 +1930,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 2db592c..0ea5963 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,12 +15,16 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -44,6 +48,57 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -57,6 +112,12 @@ static inline JsonPathExecResult recursiveExecuteUnwrap(JsonPathExecContext *cxt
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -2724,3 +2785,419 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr *expr = lfirst(lc);
+
+		cxt->colexprs[i++].expr = ExecInitExpr(expr, ps);
+	}
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (!DatumGetPointer(scan->current)) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExprPassingCaseValue(estate, econtext, isnull,
+											  scan->current, false);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 7320c1f..548a955 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -465,6 +465,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8877,6 +8879,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -9911,16 +9916,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10024,6 +10027,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index a5e0853..e87955d 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -785,6 +785,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							JsonReturning *returning,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 14c387a..e107111 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -194,6 +194,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -483,6 +485,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4b6732e..52ec5b8 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1439,6 +1439,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1509,6 +1521,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typename;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4bfa016..19745dc 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,12 +73,19 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  */
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace uri */
 	List	   *ns_names;		/* list of namespace names */
 	Node	   *docexpr;		/* input document expression */
@@ -89,7 +96,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1182,7 +1191,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1335,6 +1345,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 233e18d..a68cd2a 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -232,6 +232,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -272,6 +273,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -315,7 +317,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 4e24bd1..8430866 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -262,6 +263,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -292,4 +294,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 5379289..a2fc10a 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -991,6 +991,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index c78096c..929c64d 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -868,6 +868,935 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -903,3 +1832,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 084c7b1..94ecf76 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -290,6 +290,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index bdb0f41..bbb188e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -265,6 +265,568 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -273,3 +835,5 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
0012-json_table-json-v09.patchtext/x-patch; name=0012-json_table-json-v09.patchDownload
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index fd095d9..e59b8ee 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -170,7 +172,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 7d19881..bf49d6f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4725,12 +4725,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 8430866..c3c5316 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -294,6 +294,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index a2fc10a..2ed8d3c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -992,10 +992,961 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1031,3 +1982,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 94ecf76..196e478 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -292,7 +292,576 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -302,3 +871,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
#3Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#2)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 10th version of JSON_TABLE patches rebased onto the latest master.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0013-json_table-v10.patchtext/x-patch; name=0013-json_table-v10.patchDownload
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 89e66de..fa8037f 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2923,9 +2923,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 900fa74..2f0d440 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -2842,7 +2842,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index d410e54..13bd16c 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2184,6 +2184,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d842670..e94c24f 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4122,7 +4122,7 @@ ExecEvalAggOrderedTransTuple(ExprState *state, ExprEvalStep *op,
 /*
  * Evaluate a expression substituting specified value in its CaseTestExpr nodes.
  */
-static Datum
+Datum
 ExecEvalExprPassingCaseValue(ExprState *estate, ExprContext *econtext,
 							 bool *isnull,
 							 Datum caseval_datum, bool caseval_isnull)
@@ -4182,6 +4182,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4243,8 +4244,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4432,6 +4439,11 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			*resnull = false;
 			break;
 
+		case IS_JSON_TABLE:
+			res = item;
+			*resnull = false;
+			break;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d",
 				 jexpr->op);
@@ -4452,6 +4464,7 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 	}
 
 	if (jexpr->op != IS_JSON_EXISTS &&
+		jexpr->op != IS_JSON_TABLE &&
 		(!empty ? jexpr->op != IS_JSON_VALUE :
 		 /* result is already coerced in DEFAULT behavior case */
 		 jexpr->on_empty.btype != JSON_BEHAVIOR_DEFAULT))
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index fed6f2b..dfae539 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -365,14 +367,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 94c1680..92f407c 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1234,6 +1234,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1244,7 +1245,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2451,6 +2454,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typename);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5394,6 +5490,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 3c5137b..f62f369 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3292,6 +3318,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ebc41ea..334cabe 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -661,6 +661,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 79cb602..76af07d 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2280,6 +2280,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3147,6 +3149,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3968,6 +3971,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typename, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 9ac2b24..c40c855 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1054,6 +1054,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1064,7 +1065,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1805,6 +1808,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4374,6 +4400,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 620c878..2f787f2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -479,6 +479,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -489,7 +490,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1403,6 +1406,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2822,6 +2852,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 8b212b5..6c3bc3d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -611,9 +611,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -622,9 +642,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -638,6 +662,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -645,6 +670,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -716,7 +743,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -726,7 +753,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -734,7 +761,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -825,7 +852,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -850,6 +877,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11935,6 +11966,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12438,6 +12482,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14852,6 +14898,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14963,6 +15013,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typename = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typename = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15728,6 +16007,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15756,6 +16036,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15912,6 +16194,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 3a02307..ebecf66 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -760,6 +774,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1049,6 +1065,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1080,6 +1108,633 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typename = jtc->typename;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE jsoin type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan =
+				plan->plan_type == JSTP_JOINED ? plan->plan1 : plan;
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			childPlan = plan->plan2;
+		}
+		else
+			childPlan = NULL;
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1211,6 +1866,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 2ea7cff..7d19881 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4411,7 +4411,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4457,14 +4457,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4718,6 +4717,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 053ae02..8ccb34a 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1662,7 +1662,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 112c776..8678a72 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1930,6 +1930,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index dd36829..7f68d31 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,12 +15,16 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -44,6 +48,57 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -57,6 +112,12 @@ static inline JsonPathExecResult recursiveExecuteUnwrap(JsonPathExecContext *cxt
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -2800,3 +2861,419 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr *expr = lfirst(lc);
+
+		cxt->colexprs[i++].expr = ExecInitExpr(expr, ps);
+	}
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (!DatumGetPointer(scan->current)) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExprPassingCaseValue(estate, econtext, isnull,
+											  scan->current, false);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 99b4b3f..ed4bdfc 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -465,6 +465,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8887,6 +8889,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -9921,16 +9926,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10034,6 +10037,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index f30bf1f..8712a27 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -786,6 +786,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							JsonReturning *returning,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 14c387a..e107111 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -194,6 +194,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -483,6 +485,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1767542..10d9b8d 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1439,6 +1439,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1509,6 +1521,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typename;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4bfa016..19745dc 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,12 +73,19 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  */
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace uri */
 	List	   *ns_names;		/* list of namespace names */
 	Node	   *docexpr;		/* input document expression */
@@ -89,7 +96,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1182,7 +1191,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1335,6 +1345,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 233e18d..a68cd2a 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -232,6 +232,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -272,6 +273,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -315,7 +317,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 4e24bd1..8430866 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -262,6 +263,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -292,4 +294,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index f7d1568..fc26f27 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1041,6 +1041,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 28c82a1..6d92b17 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -918,6 +918,935 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -953,3 +1882,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 6146c45..896941c 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index a801bcf..3705e01 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,568 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,3 +847,5 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
0014-json_table-json-v10.patchtext/x-patch; name=0014-json_table-json-v10.patchDownload
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index dfae539..15d2d32 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -164,7 +166,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 7d19881..bf49d6f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4725,12 +4725,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 8430866..c3c5316 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -294,6 +294,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index fc26f27..7a56733 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1042,10 +1042,961 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1081,3 +2032,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 896941c..babc859 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -304,7 +304,576 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -314,3 +883,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
#4Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#3)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 11th version of JSON_TABLE patches rebased onto the latest master.

Fixed PLAN DEFAULT flags assignment in gram.y.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0013-json_table-v11.patchtext/x-patch; name=0013-json_table-v11.patchDownload
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 89e66de..fa8037f 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2923,9 +2923,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 900fa74..2f0d440 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -2842,7 +2842,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index d410e54..13bd16c 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2184,6 +2184,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d842670..e94c24f 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4122,7 +4122,7 @@ ExecEvalAggOrderedTransTuple(ExprState *state, ExprEvalStep *op,
 /*
  * Evaluate a expression substituting specified value in its CaseTestExpr nodes.
  */
-static Datum
+Datum
 ExecEvalExprPassingCaseValue(ExprState *estate, ExprContext *econtext,
 							 bool *isnull,
 							 Datum caseval_datum, bool caseval_isnull)
@@ -4182,6 +4182,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4243,8 +4244,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4432,6 +4439,11 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			*resnull = false;
 			break;
 
+		case IS_JSON_TABLE:
+			res = item;
+			*resnull = false;
+			break;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d",
 				 jexpr->op);
@@ -4452,6 +4464,7 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 	}
 
 	if (jexpr->op != IS_JSON_EXISTS &&
+		jexpr->op != IS_JSON_TABLE &&
 		(!empty ? jexpr->op != IS_JSON_VALUE :
 		 /* result is already coerced in DEFAULT behavior case */
 		 jexpr->on_empty.btype != JSON_BEHAVIOR_DEFAULT))
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index fed6f2b..dfae539 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -365,14 +367,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 0171388..1386831 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1234,6 +1234,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1244,7 +1245,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2451,6 +2454,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typename);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5395,6 +5491,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index c0ce2d2..b8ce7a2 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3293,6 +3319,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ebc41ea..334cabe 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -661,6 +661,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 79cb602..76af07d 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2280,6 +2280,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3147,6 +3149,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3968,6 +3971,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typename, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index ca2de9f..21a9ec8 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1054,6 +1054,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1064,7 +1065,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1805,6 +1808,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4375,6 +4401,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 620c878..2f787f2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -479,6 +479,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -489,7 +490,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1403,6 +1406,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2822,6 +2852,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 4210296..df20def 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -611,9 +611,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -622,9 +642,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -638,6 +662,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -645,6 +670,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -716,7 +743,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -726,7 +753,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -734,7 +761,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -825,7 +852,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -850,6 +877,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11938,6 +11969,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12441,6 +12485,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14856,6 +14902,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14967,6 +15017,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typename = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typename = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTP_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTP_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15732,6 +16011,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15760,6 +16040,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15916,6 +16198,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 3a02307..54ce2ae 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -760,6 +774,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1049,6 +1065,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1080,6 +1108,633 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typename = jtc->typename;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan =
+				plan->plan_type == JSTP_JOINED ? plan->plan1 : plan;
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			childPlan = plan->plan2;
+		}
+		else
+			childPlan = NULL;
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1211,6 +1866,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 2ea7cff..7d19881 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4411,7 +4411,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4457,14 +4457,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4718,6 +4717,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 053ae02..8ccb34a 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1662,7 +1662,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index e5a71c5..74bb958 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1943,6 +1943,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index dd36829..7f68d31 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,12 +15,16 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -44,6 +48,57 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -57,6 +112,12 @@ static inline JsonPathExecResult recursiveExecuteUnwrap(JsonPathExecContext *cxt
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -2800,3 +2861,419 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr *expr = lfirst(lc);
+
+		cxt->colexprs[i++].expr = ExecInitExpr(expr, ps);
+	}
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (!DatumGetPointer(scan->current)) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExprPassingCaseValue(estate, econtext, isnull,
+											  scan->current, false);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a167232..58ed084 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -467,6 +467,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8903,6 +8905,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -9937,16 +9942,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10050,6 +10053,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index f30bf1f..8712a27 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -786,6 +786,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							JsonReturning *returning,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 14c387a..e107111 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -194,6 +194,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -483,6 +485,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 5c2585e..be502f5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1440,6 +1440,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1510,6 +1522,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typename;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4bfa016..19745dc 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,12 +73,19 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  */
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace uri */
 	List	   *ns_names;		/* list of namespace names */
 	Node	   *docexpr;		/* input document expression */
@@ -89,7 +96,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1182,7 +1191,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1335,6 +1345,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 233e18d..a68cd2a 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -232,6 +232,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -272,6 +273,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -315,7 +317,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 4e24bd1..8430866 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -262,6 +263,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -292,4 +294,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index f7d1568..fc26f27 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1041,6 +1041,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 28c82a1..6d92b17 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -918,6 +918,935 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -953,3 +1882,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 6146c45..896941c 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index a801bcf..3705e01 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,568 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,3 +847,5 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
0014-json_table-json-v11.patchtext/x-patch; name=0014-json_table-json-v11.patchDownload
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index dfae539..15d2d32 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -164,7 +166,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 7d19881..bf49d6f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4725,12 +4725,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 8430866..c3c5316 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -294,6 +294,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index fc26f27..7a56733 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1042,10 +1042,961 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1081,3 +2032,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 896941c..babc859 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -304,7 +304,576 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -314,3 +883,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
#5Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#4)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 12th version of JSON_TABLE patches rebased onto the latest master.

Fixed JSON_TABLE plan validation.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0014-json_table-v12.patchtext/x-patch; name=0014-json_table-v12.patchDownload
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 89e66de..fa8037f 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2923,9 +2923,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 900fa74..2f0d440 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -2842,7 +2842,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index d410e54..13bd16c 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2184,6 +2184,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d842670..e94c24f 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4122,7 +4122,7 @@ ExecEvalAggOrderedTransTuple(ExprState *state, ExprEvalStep *op,
 /*
  * Evaluate a expression substituting specified value in its CaseTestExpr nodes.
  */
-static Datum
+Datum
 ExecEvalExprPassingCaseValue(ExprState *estate, ExprContext *econtext,
 							 bool *isnull,
 							 Datum caseval_datum, bool caseval_isnull)
@@ -4182,6 +4182,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4243,8 +4244,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4432,6 +4439,11 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			*resnull = false;
 			break;
 
+		case IS_JSON_TABLE:
+			res = item;
+			*resnull = false;
+			break;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d",
 				 jexpr->op);
@@ -4452,6 +4464,7 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 	}
 
 	if (jexpr->op != IS_JSON_EXISTS &&
+		jexpr->op != IS_JSON_TABLE &&
 		(!empty ? jexpr->op != IS_JSON_VALUE :
 		 /* result is already coerced in DEFAULT behavior case */
 		 jexpr->on_empty.btype != JSON_BEHAVIOR_DEFAULT))
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index fed6f2b..dfae539 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -365,14 +367,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 0171388..1386831 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1234,6 +1234,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1244,7 +1245,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2451,6 +2454,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typename);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5395,6 +5491,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index c0ce2d2..b8ce7a2 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3293,6 +3319,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ebc41ea..334cabe 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -661,6 +661,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 79cb602..76af07d 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2280,6 +2280,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3147,6 +3149,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3968,6 +3971,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typename, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index ca2de9f..21a9ec8 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1054,6 +1054,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1064,7 +1065,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1805,6 +1808,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4375,6 +4401,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 620c878..2f787f2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -479,6 +479,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -489,7 +490,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1403,6 +1406,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2822,6 +2852,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 13d69b4..d9315b4 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -612,9 +612,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -623,9 +643,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -639,6 +663,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -646,6 +671,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -717,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -727,7 +754,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -735,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -826,7 +853,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -851,6 +878,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11955,6 +11986,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12458,6 +12502,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14873,6 +14919,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14984,6 +15034,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typename = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typename = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTP_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTP_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15749,6 +16028,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15777,6 +16057,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15933,6 +16215,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 3a02307..ad3768d 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -760,6 +774,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1049,6 +1065,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1080,6 +1108,640 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typename = jtc->typename;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1211,6 +1873,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 2ea7cff..7d19881 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4411,7 +4411,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4457,14 +4457,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4718,6 +4717,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 053ae02..8ccb34a 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1662,7 +1662,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index e5a71c5..74bb958 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1943,6 +1943,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 720d6ea..f3441b7 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,12 +15,16 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -44,6 +48,57 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -57,6 +112,12 @@ static inline JsonPathExecResult recursiveExecuteUnwrap(JsonPathExecContext *cxt
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -2792,3 +2853,419 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr *expr = lfirst(lc);
+
+		cxt->colexprs[i++].expr = ExecInitExpr(expr, ps);
+	}
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (!DatumGetPointer(scan->current)) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExprPassingCaseValue(estate, econtext, isnull,
+											  scan->current, false);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a167232..58ed084 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -467,6 +467,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8903,6 +8905,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -9937,16 +9942,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10050,6 +10053,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index f30bf1f..8712a27 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -786,6 +786,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							JsonReturning *returning,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 14c387a..e107111 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -194,6 +194,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -483,6 +485,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 5c2585e..be502f5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1440,6 +1440,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1510,6 +1522,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typename;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4bfa016..19745dc 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,12 +73,19 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  */
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace uri */
 	List	   *ns_names;		/* list of namespace names */
 	Node	   *docexpr;		/* input document expression */
@@ -89,7 +96,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1182,7 +1191,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1335,6 +1345,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 233e18d..a68cd2a 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -232,6 +232,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -272,6 +273,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -315,7 +317,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 2c466f6..c6ce8d9 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -293,6 +294,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -323,4 +325,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index f7d1568..fc26f27 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1041,6 +1041,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 28c82a1..da2104c 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -918,6 +918,952 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -953,3 +1899,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 6146c45..896941c 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index a801bcf..2b7d25d 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,582 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,3 +861,5 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
0015-json_table-json-v12.patchtext/x-patch; name=0015-json_table-json-v12.patchDownload
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index dfae539..15d2d32 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -164,7 +166,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 7d19881..bf49d6f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4725,12 +4725,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index c6ce8d9..356216f 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -325,6 +325,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index fc26f27..97c53dd 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1042,10 +1042,978 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1081,3 +2049,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 896941c..90c52c3 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -304,7 +304,590 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -314,3 +897,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
#6Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#5)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 13th version of JSON_TABLE patches rebased onto the latest master.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0014-json_table-v13.patchtext/x-patch; name=0014-json_table-v13.patchDownload
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 89e66de..fa8037f 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2923,9 +2923,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index f0dfef5..567f33a 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -2842,7 +2842,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 35b53a2..3422caf 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2187,6 +2187,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 58e01fe..12e2ae3 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4148,6 +4148,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4213,8 +4214,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4404,6 +4411,11 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			*resnull = false;
 			break;
 
+		case IS_JSON_TABLE:
+			res = item;
+			*resnull = false;
+			break;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d",
 				 jexpr->op);
@@ -4424,6 +4436,7 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 	}
 
 	if (jexpr->op != IS_JSON_EXISTS &&
+		jexpr->op != IS_JSON_TABLE &&
 		(!empty ? jexpr->op != IS_JSON_VALUE :
 		 /* result is already coerced in DEFAULT behavior case */
 		 jexpr->on_empty.btype != JSON_BEHAVIOR_DEFAULT))
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index fed6f2b..dfae539 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -365,14 +367,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 0171388..1386831 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1234,6 +1234,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1244,7 +1245,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2451,6 +2454,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typename);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5395,6 +5491,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index c0ce2d2..b8ce7a2 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3293,6 +3319,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ebc41ea..334cabe 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -661,6 +661,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 79cb602..76af07d 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2280,6 +2280,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3147,6 +3149,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3968,6 +3971,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typename, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 9ac883c..e163fa5 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1054,6 +1054,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1064,7 +1065,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1805,6 +1808,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4375,6 +4401,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 620c878..2f787f2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -479,6 +479,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -489,7 +490,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1403,6 +1406,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2822,6 +2852,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 13d69b4..d9315b4 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -612,9 +612,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -623,9 +643,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -639,6 +663,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -646,6 +671,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -717,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -727,7 +754,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -735,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -826,7 +853,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -851,6 +878,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11955,6 +11986,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12458,6 +12502,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14873,6 +14919,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14984,6 +15034,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typename = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typename = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTP_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTP_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15749,6 +16028,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15777,6 +16057,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15933,6 +16215,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 3a02307..ad3768d 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -760,6 +774,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1049,6 +1065,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1080,6 +1108,640 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typename = jtc->typename;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1211,6 +1873,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 2ea7cff..7d19881 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4411,7 +4411,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4457,14 +4457,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4718,6 +4717,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 053ae02..8ccb34a 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1662,7 +1662,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index e5a71c5..74bb958 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1943,6 +1943,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 01adf2f..5bb1327 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,12 +15,16 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -44,6 +48,58 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -57,6 +113,12 @@ static inline JsonPathExecResult recursiveExecuteUnwrap(JsonPathExecContext *cxt
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -2794,3 +2856,429 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a167232..58ed084 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -467,6 +467,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8903,6 +8905,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -9937,16 +9942,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10050,6 +10053,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index a943ebd..d93a82b 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -787,6 +787,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							JsonReturning *returning,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 14c387a..e107111 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -194,6 +194,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -483,6 +485,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 5c2585e..be502f5 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1440,6 +1440,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1510,6 +1522,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typename;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4bfa016..19745dc 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,12 +73,19 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  */
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace uri */
 	List	   *ns_names;		/* list of namespace names */
 	Node	   *docexpr;		/* input document expression */
@@ -89,7 +96,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1182,7 +1191,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1335,6 +1345,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 233e18d..a68cd2a 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -232,6 +232,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -272,6 +273,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -315,7 +317,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 2c466f6..c6ce8d9 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -293,6 +294,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -323,4 +325,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index f7d1568..fc26f27 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1041,6 +1041,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 28c82a1..da2104c 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -918,6 +918,952 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -953,3 +1899,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 6146c45..896941c 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index a801bcf..2b7d25d 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,582 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,3 +861,5 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
0015-json_table-json-v13.patchtext/x-patch; name=0015-json_table-json-v13.patchDownload
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index dfae539..15d2d32 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -164,7 +166,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 7d19881..bf49d6f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4725,12 +4725,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index c6ce8d9..356216f 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -325,6 +325,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index fc26f27..97c53dd 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1042,10 +1042,978 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1081,3 +2049,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 896941c..90c52c3 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -304,7 +304,590 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -314,3 +897,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
#7Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#6)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 15th version of JSON_TABLE patches.

Implicit root path name assignment was disabled (it is unclear from standard).
Now all JSON path names are required if the explicit PLAN clause is used.

The documentation for JSON_TABLE can be found now in a separate patch:
/messages/by-id/732208d3-56c3-25a4-8f08-3be1d54ad51b@postgrespro.ru

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0015-json_table-v15.patchtext/x-patch; name=0015-json_table-v15.patchDownload
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 1f0e581..b574348 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2924,9 +2924,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 73d94b7..5997822 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -2925,7 +2925,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 5b84312..2cee26f 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2191,6 +2191,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index b3b3b08..1ca6d7b 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4170,6 +4170,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4235,8 +4236,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4426,6 +4433,11 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			*resnull = false;
 			break;
 
+		case IS_JSON_TABLE:
+			res = item;
+			*resnull = false;
+			break;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d",
 				 jexpr->op);
@@ -4446,6 +4458,7 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 	}
 
 	if (jexpr->op != IS_JSON_EXISTS &&
+		jexpr->op != IS_JSON_TABLE &&
 		(!empty ? jexpr->op != IS_JSON_VALUE :
 		 /* result is already coerced in DEFAULT behavior case */
 		 jexpr->on_empty.btype != JSON_BEHAVIOR_DEFAULT))
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index fed6f2b..dfae539 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -365,14 +367,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 8f51a0e..fe3977a 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1288,6 +1288,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1298,7 +1299,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2505,6 +2508,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typename);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5446,6 +5542,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index cd3ee22..d22d934 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3286,6 +3312,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ebc41ea..334cabe 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -661,6 +661,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index f699977..c201ebf 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2291,6 +2291,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3172,6 +3174,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3993,6 +3996,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typename, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 9529717..79c0bc0 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1108,6 +1108,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1118,7 +1119,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1859,6 +1862,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4432,6 +4458,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 6954854..00397c0 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -479,6 +479,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -489,7 +490,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1403,6 +1406,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2880,6 +2910,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 13ab627..259cd5b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -613,9 +613,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -624,9 +644,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -640,6 +664,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -647,6 +672,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -718,7 +745,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -728,7 +755,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -736,7 +763,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -827,7 +854,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -852,6 +879,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11989,6 +12020,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12492,6 +12536,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14907,6 +14953,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -15018,6 +15068,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typename = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typename = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTP_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTP_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15787,6 +16066,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15815,6 +16095,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15971,6 +16253,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index e147880..791414c 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -760,6 +774,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1049,6 +1065,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1080,6 +1108,642 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typename = jtc->typename;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1211,6 +1875,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index ab24b35..cb6407a 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4417,7 +4417,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4463,14 +4463,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4724,6 +4723,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index bf5df26..47b9831 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1662,7 +1662,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 7a43515..b40de13 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1944,6 +1944,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index a252383..bf3275d 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,12 +15,16 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -55,6 +59,58 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -64,6 +120,11 @@ static inline JsonPathExecResult recursiveExecuteUnwrap(JsonPathExecContext *cxt
 
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
 
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
@@ -2813,3 +2874,429 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d6776a0..3e4b35f 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -469,6 +469,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8940,6 +8942,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -9974,16 +9979,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10087,6 +10090,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index bd3fbee..561e9a9 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -793,6 +793,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 4527b5e..25f1b46 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -198,6 +198,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -486,6 +488,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 857f0b5..1622f41 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1442,6 +1442,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1512,6 +1524,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typename;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4bfa016..19745dc 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,12 +73,19 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  */
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace uri */
 	List	   *ns_names;		/* list of namespace names */
 	Node	   *docexpr;		/* input document expression */
@@ -89,7 +96,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1182,7 +1191,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1335,6 +1345,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 7732c1b..95eae04 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -233,6 +233,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -273,6 +274,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -316,7 +318,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 4071093..c469010 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -282,6 +283,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -312,4 +314,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index f7d1568..fc26f27 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1041,6 +1041,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index c516870..99e6306 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -918,6 +918,952 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -953,6 +1899,11 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
 SELECT i::text::jsonb AS js
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 6146c45..896941c 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 857bef4..7dbdfc2 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,582 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,6 +861,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
 
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
@@ -300,4 +878,3 @@ SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value
 EXPLAIN (COSTS OFF)
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
-
0016-json_table-json-v15.patchtext/x-patch; name=0016-json_table-json-v15.patchDownload
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index dfae539..15d2d32 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -164,7 +166,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index cb6407a..14fa2e6 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4731,12 +4731,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index c469010..fa4346e 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -314,6 +314,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index fc26f27..4ef91d1 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1042,10 +1042,978 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       | t    |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1081,3 +2049,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 896941c..90c52c3 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -304,7 +304,590 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -314,3 +897,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
#8Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#7)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 16th version of JSON_TABLE patches.

Changed only results of regression tests after the implicit coercion via I/O
was removed from JSON_VALUE.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0015-json_table-v16.patchtext/x-patch; name=0015-json_table-v16.patchDownload
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 1f0e581..b574348 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2924,9 +2924,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 73d94b7..5997822 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -2925,7 +2925,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 5b84312..2cee26f 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2191,6 +2191,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 25dc5e0..1642b0d 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4170,6 +4170,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4235,8 +4236,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4443,6 +4450,10 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			return BoolGetDatum((isjsonb ? JsonbPathExists : JsonPathExists)
 				(item, path, op->d.jsonexpr.args));
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index fed6f2b..dfae539 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -365,14 +367,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 8f51a0e..fe3977a 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1288,6 +1288,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1298,7 +1299,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2505,6 +2508,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typename);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5446,6 +5542,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index cd3ee22..d22d934 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3286,6 +3312,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ebc41ea..334cabe 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -661,6 +661,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index f699977..c201ebf 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2291,6 +2291,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3172,6 +3174,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3993,6 +3996,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typename, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 9529717..79c0bc0 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1108,6 +1108,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1118,7 +1119,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1859,6 +1862,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4432,6 +4458,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 6954854..00397c0 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -479,6 +479,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -489,7 +490,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1403,6 +1406,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2880,6 +2910,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 1bf4a1e..6c850bf 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -613,9 +613,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -624,9 +644,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -640,6 +664,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -647,6 +672,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -718,7 +745,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -728,7 +755,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -736,7 +763,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -827,7 +854,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -852,6 +879,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11989,6 +12020,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12492,6 +12536,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14907,6 +14953,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -15018,6 +15068,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typename = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typename = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTP_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTP_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15787,6 +16066,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15815,6 +16095,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15971,6 +16253,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index e147880..791414c 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -760,6 +774,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1049,6 +1065,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1080,6 +1108,642 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typename = jtc->typename;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1211,6 +1875,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index ab24b35..cb6407a 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4417,7 +4417,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4463,14 +4463,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4724,6 +4723,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index bf5df26..47b9831 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1662,7 +1662,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 7a43515..b40de13 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1944,6 +1944,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index a252383..bf3275d 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,12 +15,16 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -55,6 +59,58 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -64,6 +120,11 @@ static inline JsonPathExecResult recursiveExecuteUnwrap(JsonPathExecContext *cxt
 
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
 
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
@@ -2813,3 +2874,429 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d6776a0..3e4b35f 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -469,6 +469,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8940,6 +8942,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -9974,16 +9979,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10087,6 +10090,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index bd3fbee..561e9a9 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -793,6 +793,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 4527b5e..25f1b46 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -198,6 +198,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -486,6 +488,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 857f0b5..1622f41 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1442,6 +1442,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1512,6 +1524,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typename;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4bfa016..19745dc 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,12 +73,19 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  */
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace uri */
 	List	   *ns_names;		/* list of namespace names */
 	Node	   *docexpr;		/* input document expression */
@@ -89,7 +96,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1182,7 +1191,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1335,6 +1345,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c340d94..8d44ec9 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -233,6 +233,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -273,6 +274,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -316,7 +318,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 4071093..c469010 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -282,6 +283,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -312,4 +314,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 190a0d6..bd7bc94 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1037,6 +1037,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index f142d0b..892d456 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -914,6 +914,952 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -949,6 +1895,11 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
 SELECT i::text::jsonb AS js
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 824cb891..1a768ad 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 74dba5e..2a0de93 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,582 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,6 +861,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
 
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
@@ -300,4 +878,3 @@ SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value
 EXPLAIN (COSTS OFF)
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
-
0016-json_table-json-v16.patchtext/x-patch; name=0016-json_table-json-v16.patchDownload
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index dfae539..15d2d32 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -164,7 +166,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perValueCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index cb6407a..14fa2e6 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4731,12 +4731,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index c469010..fa4346e 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -314,6 +314,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bd7bc94..6faf454 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1038,10 +1038,978 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find 'x' passed variable
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1077,3 +2045,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 1a768ad..3b9e45e 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -304,7 +304,590 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -314,3 +897,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
#9Dmitry Dolgov
9erthalion6@gmail.com
In reply to: Nikita Glukhov (#8)
Re: SQL/JSON: JSON_TABLE

On Tue, Jul 3, 2018 at 4:50 PM Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:

Attached 16th version of JSON_TABLE patches.

Changed only results of regression tests after the implicit coercion via I/O
was removed from JSON_VALUE.

Thank you for working on this patch! Unfortunately, the current version of
patch 0015-json_table doesn't not apply anymore without conflicts, could you
please rebase it? In the meantime I'll try to provide some review.

#10Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Dmitry Dolgov (#9)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 26.11.2018 15:55, Dmitry Dolgov wrote:

On Tue, Jul 3, 2018 at 4:50 PM Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:

Attached 16th version of JSON_TABLE patches.

Changed only results of regression tests after the implicit coercion via I/O
was removed from JSON_VALUE.

Thank you for working on this patch! Unfortunately, the current version of
patch 0015-json_table doesn't not apply anymore without conflicts, could you
please rebase it? In the meantime I'll try to provide some review.

Attached 20th version of the patches rebased onto the current master.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0010-JSON_TABLE-v20.patchtext/x-patch; name=0010-JSON_TABLE-v20.patchDownload
From d2f3c3df569acafed5f4a2dbc85233b361699530 Mon Sep 17 00:00:00 2001
From: Nikita Glukhov <n.gluhov@postgrespro.ru>
Date: Mon, 26 Nov 2018 19:03:43 +0300
Subject: [PATCH 10/11] JSON_TABLE

---
 contrib/pg_stat_statements/pg_stat_statements.c |   2 +
 src/backend/commands/explain.c                  |   4 +-
 src/backend/executor/execExpr.c                 |   1 +
 src/backend/executor/execExprInterp.c           |  11 +
 src/backend/executor/nodeTableFuncscan.c        |  23 +-
 src/backend/nodes/copyfuncs.c                   | 111 +++
 src/backend/nodes/equalfuncs.c                  |  32 +
 src/backend/nodes/makefuncs.c                   |  19 +
 src/backend/nodes/nodeFuncs.c                   |  27 +
 src/backend/nodes/outfuncs.c                    |  32 +
 src/backend/nodes/readfuncs.c                   |  34 +
 src/backend/parser/gram.y                       | 291 +++++++-
 src/backend/parser/parse_clause.c               | 689 +++++++++++++++++
 src/backend/parser/parse_expr.c                 |  24 +-
 src/backend/parser/parse_relation.c             |   3 +-
 src/backend/parser/parse_target.c               |   3 +
 src/backend/utils/adt/jsonpath_exec.c           | 494 ++++++++++++
 src/backend/utils/adt/ruleutils.c               | 285 ++++++-
 src/include/executor/execExpr.h                 |   3 +
 src/include/nodes/makefuncs.h                   |   2 +
 src/include/nodes/nodes.h                       |   5 +
 src/include/nodes/parsenodes.h                  |  89 +++
 src/include/nodes/primnodes.h                   |  41 +-
 src/include/parser/kwlist.h                     |   4 +
 src/include/utils/jsonpath.h                    |   6 +-
 src/include/utils/jsonpath_json.h               |   1 +
 src/test/regress/expected/json_sqljson.out      |   5 +
 src/test/regress/expected/jsonb_sqljson.out     | 951 ++++++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql           |   4 +
 src/test/regress/sql/jsonb_sqljson.sql          | 579 ++++++++++++++-
 30 files changed, 3748 insertions(+), 27 deletions(-)

diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 832f7e3..f560554 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2924,9 +2924,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index de09ded..b676881 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3021,7 +3021,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index d8dac35..3124be2 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2193,6 +2193,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 973227d..ca1a96c 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4174,6 +4174,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4239,8 +4240,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4447,6 +4454,10 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			return BoolGetDatum((isjsonb ? JsonbPathExists : JsonPathExists)
 				(item, path, op->d.jsonexpr.args));
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index a79e4cb..e8f997a 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -162,8 +163,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -384,14 +386,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 175645c..974d92b 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1297,6 +1297,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1307,7 +1308,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2514,6 +2517,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5459,6 +5555,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 190e48e..c7407b9 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3286,6 +3312,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index a1e825e..e78c4c1 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -660,6 +660,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index b158d12..9ffbc15 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2291,6 +2291,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3172,6 +3174,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3993,6 +3996,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 7965210..6a17253 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1120,6 +1120,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1130,7 +1131,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1871,6 +1874,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4464,6 +4490,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 80c95e8..61af0a9 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -490,6 +490,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -500,7 +501,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1414,6 +1417,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2929,6 +2959,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0001199..1110e23 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -613,9 +613,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -624,9 +644,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -640,6 +664,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -647,6 +672,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -718,7 +745,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -728,7 +755,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -736,7 +763,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -827,7 +854,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -852,6 +879,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11962,6 +11993,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12464,6 +12508,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14879,6 +14925,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14990,6 +15040,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTP_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTP_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15759,6 +16038,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15787,6 +16067,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15943,6 +16225,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 4ba5120..d41ad6a 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -721,6 +735,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1011,6 +1027,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1042,6 +1070,642 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1173,6 +1837,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 9cfba1d..112fa59 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4417,7 +4417,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4463,14 +4463,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4724,6 +4723,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 378cbcb..4120d21 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1685,7 +1685,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 1a7e845..2252299 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1950,6 +1950,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 2d7c830..63f926d 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,7 +15,9 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
@@ -23,6 +25,8 @@
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -73,6 +77,58 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -88,6 +144,11 @@ static inline JsonbValue *wrapItem(JsonbValue *jbv);
 
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
 
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
@@ -121,6 +182,13 @@ JsonValueListHead(JsonValueList *jvl)
 	return jvl->singleton ? jvl->singleton : linitial(jvl->list);
 }
 
+static inline void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NIL;
+}
+
 static inline List *
 JsonValueListGetList(JsonValueList *jvl)
 {
@@ -3201,3 +3269,429 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 830e1a4..1233a5f 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -470,6 +470,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -9011,6 +9013,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -10040,16 +10045,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10153,6 +10156,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 2b3e98c..9ec6d92 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -799,6 +799,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 05d3eb7..984c890 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -199,6 +199,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -487,6 +489,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 377297b..2cf90e2 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1454,6 +1454,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1524,6 +1536,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index a53ab6c..72f9be8 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1197,7 +1206,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1350,6 +1360,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c340d94..8d44ec9 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -233,6 +233,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -273,6 +274,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -316,7 +318,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 2102b3d..22bb19b 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -310,6 +311,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -340,4 +342,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/include/utils/jsonpath_json.h b/src/include/utils/jsonpath_json.h
index e8bdc65..acb1e75 100644
--- a/src/include/utils/jsonpath_json.h
+++ b/src/include/utils/jsonpath_json.h
@@ -95,6 +95,7 @@
 #define JsonbPathExists		JsonPathExists
 #define JsonbPathQuery		JsonPathQuery
 #define JsonbPathValue		JsonPathValue
+#define JsonbTableRoutine	JsonTableRoutine
 
 static inline JsonbValue *
 JsonbInitBinary(JsonbValue *jbv, Json *jb)
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 2f7be26..68634d6 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1037,6 +1037,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index e63ddbe..ebbdd3d 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -914,6 +914,952 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable 'x'
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -949,6 +1895,11 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
 SELECT i::text::jsonb AS js
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 3a39f60..6fb0c6a 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 8bb9e01..bae79cb 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,582 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,6 +861,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
 
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
@@ -300,4 +878,3 @@ SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value
 EXPLAIN (COSTS OFF)
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
-
-- 
2.7.4

0011-JSON_TABLE-for-json-type-v20.patchtext/x-patch; name=0011-JSON_TABLE-for-json-type-v20.patchDownload
From 288d39c4bf832c538d562d9b42e3951e140ba779 Mon Sep 17 00:00:00 2001
From: Nikita Glukhov <n.gluhov@postgrespro.ru>
Date: Mon, 26 Nov 2018 19:03:43 +0300
Subject: [PATCH 11/11] JSON_TABLE for json type

---
 src/backend/executor/nodeTableFuncscan.c   |   5 +-
 src/backend/parser/parse_expr.c            |   6 -
 src/include/utils/jsonpath.h               |   1 +
 src/test/regress/expected/json_sqljson.out | 981 ++++++++++++++++++++++++++++-
 src/test/regress/sql/json_sqljson.sql      | 587 ++++++++++++++++-
 5 files changed, 1568 insertions(+), 12 deletions(-)

diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index e8f997a..6384efd 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -165,7 +167,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 112fa59..6fd4c6a 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4731,12 +4731,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 22bb19b..2fc4cbe 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -342,6 +342,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 68634d6..21658dd 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1038,10 +1038,978 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable 'x'
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1077,3 +2045,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 6fb0c6a..8508957 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -304,7 +304,590 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -314,3 +897,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
-- 
2.7.4

#11Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#10)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 21st version of the patches rebased onto the current master.

You can also see all SQL/JSON v21 patches successfully applied in our GitHub
repository on the following branches:
https://github.com/postgrespro/sqljson/tree/sqljson_v21 (one commit per patch)
https://github.com/postgrespro/sqljson/tree/sqljson (original commit history)

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0012-JSON_TABLE-v21.patchtext/x-patch; name=0012-JSON_TABLE-v21.patchDownload
From 783e25e69f7a6071c23b6a2cfe83bf091adbca77 Mon Sep 17 00:00:00 2001
From: Nikita Glukhov <n.gluhov@postgrespro.ru>
Date: Tue, 4 Dec 2018 02:05:11 +0300
Subject: [PATCH 12/13] JSON_TABLE

---
 contrib/pg_stat_statements/pg_stat_statements.c |   2 +
 src/backend/commands/explain.c                  |   4 +-
 src/backend/executor/execExpr.c                 |   1 +
 src/backend/executor/execExprInterp.c           |  11 +
 src/backend/executor/nodeTableFuncscan.c        |  23 +-
 src/backend/nodes/copyfuncs.c                   | 111 +++
 src/backend/nodes/equalfuncs.c                  |  32 +
 src/backend/nodes/makefuncs.c                   |  19 +
 src/backend/nodes/nodeFuncs.c                   |  27 +
 src/backend/nodes/outfuncs.c                    |  32 +
 src/backend/nodes/readfuncs.c                   |  34 +
 src/backend/parser/gram.y                       | 291 +++++++-
 src/backend/parser/parse_clause.c               | 689 +++++++++++++++++
 src/backend/parser/parse_expr.c                 |  24 +-
 src/backend/parser/parse_relation.c             |   3 +-
 src/backend/parser/parse_target.c               |   3 +
 src/backend/utils/adt/jsonpath_exec.c           | 494 ++++++++++++
 src/backend/utils/adt/ruleutils.c               | 285 ++++++-
 src/include/executor/execExpr.h                 |   3 +
 src/include/nodes/makefuncs.h                   |   2 +
 src/include/nodes/nodes.h                       |   5 +
 src/include/nodes/parsenodes.h                  |  89 +++
 src/include/nodes/primnodes.h                   |  41 +-
 src/include/parser/kwlist.h                     |   4 +
 src/include/utils/jsonpath.h                    |   6 +-
 src/include/utils/jsonpath_json.h               |   1 +
 src/test/regress/expected/json_sqljson.out      |   5 +
 src/test/regress/expected/jsonb_sqljson.out     | 951 ++++++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql           |   4 +
 src/test/regress/sql/jsonb_sqljson.sql          | 579 ++++++++++++++-
 30 files changed, 3748 insertions(+), 27 deletions(-)

diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 832f7e3..f560554 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2924,9 +2924,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index de09ded..b676881 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3021,7 +3021,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index d8dac35..3124be2 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2193,6 +2193,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->var.cb_arg = var;
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 973227d..ca1a96c 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4174,6 +4174,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4239,8 +4240,14 @@ EvalJsonPathVar(void *cxt, bool *isnull)
 
 	if (!ecxt->evaluated)
 	{
+		MemoryContext oldcxt = ecxt->mcxt ?
+			MemoryContextSwitchTo(ecxt->mcxt) : NULL;
+
 		ecxt->value = ExecEvalExpr(ecxt->estate, ecxt->econtext, &ecxt->isnull);
 		ecxt->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	*isnull = ecxt->isnull;
@@ -4447,6 +4454,10 @@ ExecEvalJsonExpr(ExprState *state, ExprEvalStep *op, ExprContext *econtext,
 			return BoolGetDatum((isjsonb ? JsonbPathExists : JsonPathExists)
 				(item, path, op->d.jsonexpr.args));
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index a79e4cb..e8f997a 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -162,8 +163,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -384,14 +386,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 175645c..974d92b 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1297,6 +1297,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1307,7 +1308,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2514,6 +2517,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						relation.h copy functions
  *
@@ -5459,6 +5555,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 190e48e..c7407b9 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -119,6 +119,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -129,7 +130,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -137,6 +140,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3286,6 +3312,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index a1e825e..e78c4c1 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -660,6 +660,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index b158d12..9ffbc15 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2291,6 +2291,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3172,6 +3174,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -3993,6 +3996,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 7965210..6a17253 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1120,6 +1120,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1130,7 +1131,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1871,6 +1874,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from relation.h.
@@ -4464,6 +4490,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 80c95e8..61af0a9 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -490,6 +490,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -500,7 +501,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1414,6 +1417,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2929,6 +2959,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0001199..1110e23 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -613,9 +613,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -624,9 +644,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -640,6 +664,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -647,6 +672,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -718,7 +745,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -728,7 +755,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -736,7 +763,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -827,7 +854,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -852,6 +879,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11962,6 +11993,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12464,6 +12508,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14879,6 +14925,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14990,6 +15040,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTP_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTP_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15759,6 +16038,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15787,6 +16067,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15943,6 +16225,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 4ba5120..d41ad6a 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -49,10 +49,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -103,6 +113,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -721,6 +735,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1011,6 +1027,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1042,6 +1070,642 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1173,6 +1837,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 9cfba1d..112fa59 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4417,7 +4417,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4463,14 +4463,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4724,6 +4723,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			if (jsexpr->returning.typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 378cbcb..4120d21 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1685,7 +1685,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 1a7e845..2252299 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1950,6 +1950,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 7224eb9..68c5a4c 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -15,7 +15,9 @@
 #include "miscadmin.h"
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "lib/stringinfo.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
@@ -23,6 +25,8 @@
 #include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/varlena.h"
 
 #ifdef JSONPATH_JSON_C
@@ -73,6 +77,58 @@ typedef struct JsonValueListIterator
 
 #define JsonValueListIteratorEnd ((ListCell *) -1)
 
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 static inline JsonPathExecResult recursiveExecute(JsonPathExecContext *cxt,
 										   JsonPathItem *jsp, JsonbValue *jb,
 										   JsonValueList *found);
@@ -88,6 +144,11 @@ static inline JsonbValue *wrapItem(JsonbValue *jbv);
 
 static inline JsonbValue *wrapItemsInArray(const JsonValueList *items);
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
 
 static inline void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
@@ -121,6 +182,13 @@ JsonValueListHead(JsonValueList *jvl)
 	return jvl->singleton ? jvl->singleton : linitial(jvl->list);
 }
 
+static inline void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NIL;
+}
+
 static inline List *
 JsonValueListGetList(JsonValueList *jvl)
 {
@@ -3217,3 +3285,429 @@ JsonbPathValue(Datum jb, JsonPath *jp, bool *empty, List *vars)
 
 	return res;
 }
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->var.varName = cstring_to_text(name->val.str);
+			var->var.typid = exprType((Node *) expr);
+			var->var.typmod = exprTypmod((Node *) expr);
+			var->var.cb = EvalJsonPathVar;
+			var->var.cb_arg = var;
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	memset(&scan->iter, 0, sizeof(scan->iter));
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, DatumGetJsonbP(item),
+						  &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		if (scan->errorOnError)
+			throwJsonPathError(res);	/* does not return */
+		else
+			JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 830e1a4..1233a5f 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -470,6 +470,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -9011,6 +9013,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -10040,16 +10045,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10153,6 +10156,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 2b3e98c..9ec6d92 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -799,6 +799,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item, bool is_jsonb,
 							struct JsonCoercionsState *coercions,
 							struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index f7aec03..78488bf 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -90,6 +90,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 05d3eb7..984c890 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -199,6 +199,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -487,6 +489,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 377297b..2cf90e2 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1454,6 +1454,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1524,6 +1536,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index a53ab6c..72f9be8 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1197,7 +1206,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1350,6 +1360,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c340d94..8d44ec9 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -233,6 +233,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -273,6 +274,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -316,7 +318,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 2102b3d..22bb19b 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,9 +15,10 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
-#include "utils/jsonb.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -310,6 +311,7 @@ typedef struct JsonPathVariableEvalContext
 	JsonPathVariable var;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -340,4 +342,6 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/include/utils/jsonpath_json.h b/src/include/utils/jsonpath_json.h
index e8bdc65..acb1e75 100644
--- a/src/include/utils/jsonpath_json.h
+++ b/src/include/utils/jsonpath_json.h
@@ -95,6 +95,7 @@
 #define JsonbPathExists		JsonPathExists
 #define JsonbPathQuery		JsonPathQuery
 #define JsonbPathValue		JsonPathValue
+#define JsonbTableRoutine	JsonTableRoutine
 
 static inline JsonbValue *
 JsonbInitBinary(JsonbValue *jbv, Json *jb)
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 2f7be26..68634d6 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1037,6 +1037,11 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index e63ddbe..ebbdd3d 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -914,6 +914,952 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable 'x'
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -949,6 +1895,11 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
 SELECT i::text::jsonb AS js
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 3a39f60..6fb0c6a 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,10 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 8bb9e01..bae79cb 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,582 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,6 +861,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
 
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
@@ -300,4 +878,3 @@ SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value
 EXPLAIN (COSTS OFF)
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
-
-- 
2.7.4

0013-JSON_TABLE-for-json-type-v21.patchtext/x-patch; name=0013-JSON_TABLE-for-json-type-v21.patchDownload
From 6bb1d6dc92707ac5f3d7d898936572b1d470dcda Mon Sep 17 00:00:00 2001
From: Nikita Glukhov <n.gluhov@postgrespro.ru>
Date: Tue, 4 Dec 2018 02:05:11 +0300
Subject: [PATCH 13/13] JSON_TABLE for json type

---
 src/backend/executor/nodeTableFuncscan.c   |   5 +-
 src/backend/parser/parse_expr.c            |   6 -
 src/include/utils/jsonpath.h               |   1 +
 src/test/regress/expected/json_sqljson.out | 981 ++++++++++++++++++++++++++++-
 src/test/regress/sql/json_sqljson.sql      | 587 ++++++++++++++++-
 5 files changed, 1568 insertions(+), 12 deletions(-)

diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index e8f997a..6384efd 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,10 +23,12 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
 #include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
@@ -165,7 +167,8 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 
 	/* Only XMLTABLE and JSON_TABLE are supported currently */
 	scanstate->routine =
-		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 112fa59..6fd4c6a 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4731,12 +4731,6 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typid = exprType(contextItemExpr);
 			jsexpr->returning.typmod = -1;
 
-			if (jsexpr->returning.typid != JSONBOID)
-				ereport(ERROR,
-						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-						 errmsg("JSON_TABLE() is not yet implemented for json type"),
-						 parser_errposition(pstate, func->location)));
-
 			break;
 	}
 
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 22bb19b..2fc4cbe 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -342,6 +342,7 @@ extern Datum JsonPathQuery(Datum json, JsonPath *jp, JsonWrapper wrapper,
 
 extern Datum EvalJsonPathVar(void *cxt, bool *isnull);
 
+extern const TableFuncRoutine JsonTableRoutine;
 extern const TableFuncRoutine JsonbTableRoutine;
 
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 68634d6..21658dd 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1038,10 +1038,978 @@ ERROR:  new row for relation "test_json_constraints" violates check constraint "
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
 -- JSON_TABLE
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
-ERROR:  JSON_TABLE() is not yet implemented for json type
-LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
-                                 ^
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable 'x'
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1077,3 +2045,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 6fb0c6a..8508957 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -304,7 +304,590 @@ DROP TABLE test_json_constraints;
 
 -- JSON_TABLE
 
-SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
 
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
@@ -314,3 +897,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
-- 
2.7.4

#12Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#11)
1 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 34th version of the patches.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0009-Implementation-of-JSON_TABLE-v34.patchtext/x-patch; name=0009-Implementation-of-JSON_TABLE-v34.patchDownload
From 06872110a5885a298306b51369a4cf176d2e7a01 Mon Sep 17 00:00:00 2001
From: Nikita Glukhov <n.gluhov@postgrespro.ru>
Date: Fri, 1 Mar 2019 03:15:19 +0300
Subject: [PATCH 09/13] Implementation of JSON_TABLE

---
 contrib/pg_stat_statements/pg_stat_statements.c |   2 +
 src/backend/commands/explain.c                  |   4 +-
 src/backend/executor/execExpr.c                 |   1 +
 src/backend/executor/execExprInterp.c           |  11 +
 src/backend/executor/nodeTableFuncscan.c        |  26 +-
 src/backend/nodes/copyfuncs.c                   | 111 +++
 src/backend/nodes/equalfuncs.c                  |  32 +
 src/backend/nodes/makefuncs.c                   |  19 +
 src/backend/nodes/nodeFuncs.c                   |  27 +
 src/backend/nodes/outfuncs.c                    |  32 +
 src/backend/nodes/readfuncs.c                   |  34 +
 src/backend/parser/gram.y                       | 291 ++++++-
 src/backend/parser/parse_clause.c               | 689 +++++++++++++++++
 src/backend/parser/parse_expr.c                 |  18 +-
 src/backend/parser/parse_relation.c             |   3 +-
 src/backend/parser/parse_target.c               |   3 +
 src/backend/utils/adt/jsonpath_exec.c           | 524 ++++++++++++-
 src/backend/utils/adt/ruleutils.c               | 285 ++++++-
 src/include/executor/execExpr.h                 |   3 +
 src/include/nodes/makefuncs.h                   |   2 +
 src/include/nodes/nodes.h                       |   5 +
 src/include/nodes/parsenodes.h                  |  89 +++
 src/include/nodes/primnodes.h                   |  41 +-
 src/include/parser/kwlist.h                     |   4 +
 src/include/utils/jsonpath.h                    |   6 +
 src/test/regress/expected/json_sqljson.out      | 979 ++++++++++++++++++++++++
 src/test/regress/expected/jsonb_sqljson.out     | 952 +++++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql           | 589 ++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql          | 579 +++++++++++++-
 29 files changed, 5334 insertions(+), 27 deletions(-)

diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index f57ae2b..9c36acd 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -2999,9 +2999,11 @@ JumbleExpr(pgssJumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 1831ea8..90e717e 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3021,7 +3021,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 35a70ff..62d6572 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2181,6 +2181,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index af965a1..28c43ae 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4187,6 +4187,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4286,8 +4287,14 @@ EvalJsonPathVar(void *cxt, bool isJsonb, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4584,6 +4591,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				return BoolGetDatum(res);
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 45d5f3c..98adecd 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -23,11 +23,14 @@
 #include "postgres.h"
 
 #include "nodes/execnodes.h"
+#include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/nodeTableFuncscan.h"
 #include "executor/tablefunc.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -162,8 +165,10 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine :
+		exprType(tf->docexpr) == JSONBOID ? &JsonbTableRoutine : &JsonTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -384,14 +389,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index edc04a5..3833fae 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1297,6 +1297,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1307,7 +1308,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2514,6 +2517,99 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5460,6 +5556,21 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 19ca47f..39bd753 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -120,6 +120,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -130,7 +131,9 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
@@ -138,6 +141,29 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 }
 
 static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
+
+	return true;
+}
+
+static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
 	COMPARE_NODE_FIELD(rel);
@@ -3291,6 +3317,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 64f88b9..e96e9f0 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -795,6 +795,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 }
 
 /*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
+/*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
  */
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 112f886..5771ac3 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2309,6 +2309,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3211,6 +3213,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4033,6 +4036,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index c7daeee..8b46757 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1021,6 +1021,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1031,7 +1032,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1772,6 +1775,29 @@ _outJsonIsPredicateOpts(StringInfo str, const JsonIsPredicateOpts *node)
 	WRITE_BOOL_FIELD(unique_keys);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
+	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4369,6 +4395,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index d01b856..70307e4 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -492,6 +492,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -502,7 +503,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1416,6 +1419,33 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
+	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -2937,6 +2967,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 5709d42..45ad865 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -612,9 +612,29 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 					json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
@@ -623,9 +643,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -639,6 +663,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -646,6 +671,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -717,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_VALUE
+	JSON_QUERY JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -727,7 +754,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NO NONE
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NO NONE
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -735,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -826,7 +853,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally should have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
+%nonassoc	COLUMNS FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN
 %nonassoc	IDENT GENERATED NULL_P PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -851,6 +878,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 /* kluge to keep xml_whitespace_option from causing shift/reduce conflicts */
 %right		PRESERVE STRIP_P
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -11945,6 +11976,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12447,6 +12491,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -14862,6 +14908,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 		;
@@ -14973,6 +15023,235 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_plan_clause_opt
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->plan = (JsonTablePlan *) $5;
+					n->on_error = $6;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format.type = JS_FORMAT_DEFAULT;
+					n->format.encoding = JS_ENC_DEFAULT;
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $3;
+					n->on_empty = $4.on_empty;
+					n->on_error = $4.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = $4;
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->columns = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_table_plan_clause_opt:
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTP_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTP_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTP_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTP_INNER; }
+			| OUTER_P									{ $$ = JSTP_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTP_UNION; }
+			| CROSS										{ $$ = JSTP_CROSS; }
+		;
 
 json_output_clause_opt:
 			RETURNING Typename json_format_clause_opt
@@ -15742,6 +16021,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NO
@@ -15770,6 +16050,8 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -15927,6 +16209,7 @@ col_name_keyword:
 			| JSON_OBJECT
 			| JSON_OBJECTAGG
 			| JSON_QUERY
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index c6ce101..e18d1d1 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -48,10 +48,20 @@
 #include "utils/builtins.h"
 #include "utils/guc.h"
 #include "utils/catcache.h"
+#include "utils/json.h"
 #include "utils/lsyscache.h"
 #include "utils/syscache.h"
 #include "utils/rel.h"
 
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
 
 /* Convenience macro for the most common makeNamespaceItem() case */
 #define makeDefaultNSItem(rte)	makeNamespaceItem(rte, true, true, false, true)
@@ -102,6 +112,10 @@ static WindowClause *findWindowClause(List *wclist, const char *name);
 static Node *transformFrameOffset(ParseState *pstate, int frameOptions,
 					 Oid rangeopfamily, Oid rangeopcintype, Oid *inRangeFunc,
 					 Node *clause);
+static JsonTableParentNode * transformJsonTableColumns(ParseState *pstate,
+						JsonTableContext *cxt, JsonTablePlan *plan,
+						List *columns, char *pathSpec, char **pathName,
+						int location);
 
 
 /*
@@ -720,6 +734,8 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	Assert(!pstate->p_lateral_active);
 	pstate->p_lateral_active = true;
 
+	tf->functype = TFT_XMLTABLE;
+
 	/* Transform and apply typecast to the row-generating expression ... */
 	Assert(rtf->rowexpr != NULL);
 	tf->rowexpr = coerce_to_specific_type(pstate,
@@ -1010,6 +1026,18 @@ transformRangeTableSample(ParseState *pstate, RangeTableSample *rts)
 	return tablesample;
 }
 
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
 /*
  * getRTEForSpecialRelationTypes
  *
@@ -1041,6 +1069,642 @@ getRTEForSpecialRelationTypes(ParseState *pstate, RangeVar *rv)
 }
 
 /*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - formatted column into JSON_QUERY()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonValueExpr *jvexpr = makeNode(JsonValueExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+
+	jfexpr->op = jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning.format = jtc->format;
+
+	common->pathname = NULL;
+	common->expr = jvexpr;
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	jvexpr->expr = (Expr *) contextItemExpr;
+	jvexpr->format.type = JS_FORMAT_DEFAULT;
+	jvexpr->format.encoding = JS_ENC_DEFAULT;
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
+		else
+		{
+			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTP_CROSS ||
+				 plan->join_type == JSTP_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchilds = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchilds++;
+		}
+	}
+
+	if (list_length(siblings) > nchilds)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
+}
+
+static Node *
+transformNestedJsonTableColumn(ParseState *pstate, JsonTableContext *cxt,
+							   JsonTableColumn *jtc, JsonTablePlan *plan)
+{
+	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
+
+	node = transformJsonTableColumns(pstate, cxt, plan,
+									 jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+	join->cross = cross;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child JSON_TABLE plan.
+ *
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
+ */
+static Node *
+transformJsonTableChildPlan(ParseState *pstate, JsonTableContext *cxt,
+							JsonTablePlan *plan, List *columns)
+{
+	JsonTableColumn *jtc = NULL;
+
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
+	{
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTP_CROSS);
+
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
+
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
+
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
+	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTP_INNER ||
+			plan->join_type == JSTP_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(pstate, cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTP_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
+
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(pstate, cxt, jtc, plan);
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(ParseState *pstate, JsonTableContext *cxt, List *columns)
+{
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+	ListCell *col;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(ParseState *pstate, JsonTableContext *cxt,
+						char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(pstate, cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(ParseState *pstate, JsonTableContext *cxt,
+						  JsonTablePlan *plan, List *columns,
+						  char *pathSpec, char **pathName, int location)
+{
+	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTP_INNER &&
+				plan->join_type != JSTP_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(pstate, plan->location)));
+
+
+		validateJsonTableChildPlan(pstate, childPlan, columns);
+	}
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(pstate, cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
+
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(pstate, cxt, childPlan,
+												  columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTP_OUTER);
+		/* else: default plan case, no children found */
+	}
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+static RangeTblEntry *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	JsonTablePlan *plan = jt->plan;
+	char	   *rootPathName = jt->common->pathname;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTP_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(pstate, &cxt, plan,
+												  jt->columns,
+												  rootPath, &rootPathName,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
+
+/*
  * transformFromClauseItem -
  *	  Transform a FROM-clause item, adding any required entries to the
  *	  range table list being built in the ParseState, and return the
@@ -1172,6 +1836,31 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rte->tablesample = transformRangeTableSample(pstate, rts);
 		return (Node *) rtr;
 	}
+	else if (IsA(n, JsonTable))
+	{
+		/* JsonTable is transformed into RangeSubselect */
+		/*
+		JsonTable *jt = castNode(JsonTable, n);
+		RangeSubselect *subselect = transformJsonTable(pstate, jt);
+
+		return transformFromClauseItem(pstate, (Node *) subselect,
+									   top_rte, top_rti, namespace);
+		*/
+		RangeTblRef *rtr;
+		RangeTblEntry *rte;
+		int			rtindex;
+
+		rte = transformJsonTable(pstate, (JsonTable *) n);
+		/* assume new rte is at end */
+		rtindex = list_length(pstate->p_rtable);
+		Assert(rte == rt_fetch(rtindex, pstate->p_rtable));
+		*top_rte = rte;
+		*top_rti = rtindex;
+		*namespace = list_make1(makeDefaultNSItem(rte));
+		rtr = makeNode(RangeTblRef);
+		rtr->rtindex = rtindex;
+		return (Node *) rtr;
+	}
 	else if (IsA(n, JoinExpr))
 	{
 		/* A newfangled join expression */
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 4d0f3bd..6b6e516 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4431,7 +4431,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4477,14 +4477,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4738,6 +4737,15 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 			jsexpr->returning.typmod = -1;
 
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning.format.type = JS_FORMAT_DEFAULT;
+			jsexpr->returning.format.encoding = JS_ENC_DEFAULT;
+			jsexpr->returning.format.location = -1;
+			jsexpr->returning.typid = exprType(contextItemExpr);
+			jsexpr->returning.typmod = -1;
+
+			break;
 	}
 
 	return (Node *) jsexpr;
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index f3b6d19..13c5fc3 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1693,7 +1693,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 3f3ba73..5bbe70b 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1952,6 +1952,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 54c0d6b..4b815b0 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,11 +61,14 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
+#include "utils/date.h"
 #include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/formatting.h"
@@ -74,7 +77,8 @@
 #include "utils/json.h"
 #include "utils/jsonapi.h"
 #include "utils/jsonpath.h"
-#include "utils/date.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -217,6 +221,60 @@ typedef struct JsonPathUserFuncContext
 	JsonValueList found;		/* resulting item list */
 } JsonPathUserFuncContext;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		outerJoin;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		cross;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+	bool		isJsonb;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -327,6 +385,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 			  JsonPathItem *jsp, JsonItem *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 			  JsonItem *jsi, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonItem *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -366,6 +425,11 @@ static void pushJsonItem(JsonItemStack *stack,
 			 JsonItemStackEntry *entry, JsonItem *item);
 static void popJsonItem(JsonItemStack *stack);
 
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan, bool isJsonb);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2752,6 +2816,14 @@ setBaseObject(JsonPathExecContext *cxt, JsonItem *jbv, int32 id)
 }
 
 static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->head = NULL;
+	jvl->tail = NULL;
+	jvl->length = 0;
+}
+
+static void
 JsonValueListAppend(JsonValueList *jvl, JsonItem *jsi)
 {
 	jsi->next = NULL;
@@ -3627,3 +3699,453 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonItem *res,
 							   "casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.cross = join->cross;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonxTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonxTableInitOpaque(TableFuncScanState *state, int natts, bool isJsonb)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+	cxt->isJsonb = isJsonb;
+
+	if (list_length(ci->passing.values) > 0)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing.values,
+				namelc, ci->passing.names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->val.str);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+static void
+JsonbTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonxTableInitOpaque(state, natts, true);
+}
+
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonxTableInitOpaque(state, natts, false);
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item, bool isJsonb)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonx	   *js = DatumGetJsonxP(item, isJsonb);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js, isJsonb,
+						  scan->errorOnError, &scan->found);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value, cxt->isJsonb);
+}
+
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a cross/union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state, bool isJsonb)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan, isJsonb);
+
+	if (state->u.join.advanceRight)
+	{
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right, isJsonb))
+			return true;
+
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left, isJsonb);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right, isJsonb))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right, isJsonb))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan, bool isJsonb)
+{
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current, isJsonb);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested, isJsonb);
+
+		if (scan->advanceNested)
+			return true;
+	}
+
+	for (;;)
+	{
+		/* fetch next row */
+		JsonItem   *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
+
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
+
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonItemToJsonxDatum(jbv, isJsonb);
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
+
+		JsonTableJoinReset(scan->nested);
+
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested, isJsonb);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root, cxt->isJsonb);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonbTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
+
+const TableFuncRoutine JsonTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 627502b..bb079d4 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -471,6 +471,8 @@ static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 				   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -9043,6 +9045,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->raw_expr, context, showimplicit);
@@ -10072,16 +10077,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10172,6 +10175,280 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	ListCell   *l1;
+	ListCell   *l2;
+	ListCell   *l3;
+	ListCell   *l4;
+	int			colnum = 0;
+
+	l2 = list_head(tf->coltypes);
+	l3 = list_head(tf->coltypmods);
+	l4 = list_head(tf->colvalexprs);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	foreach(l1, tf->colnames)
+	{
+		char	   *colname = strVal(lfirst(l1));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+
+		typid = lfirst_oid(l2);
+		l2 = lnext(l2);
+		typmod = lfirst_int(l3);
+		l3 = lnext(l3);
+		colexpr = castNode(JsonExpr, lfirst(l4));
+		l4 = lnext(l4);
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_QUERY)
+			appendStringInfoString(buf,
+								   colexpr->format.type == JS_FORMAT_JSONB ?
+								   " FORMAT JSONB" : " FORMAT JSON");
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		if (colexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(buf, " WITH CONDITIONAL WRAPPER");
+
+		if (colexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (colexpr->omit_quotes)
+			appendStringInfo(buf, " OMIT QUOTES");
+
+		if (colexpr->on_empty.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_empty, context, "EMPTY");
+
+		if (colexpr->on_error.btype != JSON_BEHAVIOR_NULL)
+			get_json_behavior(&colexpr->on_error, context, "ERROR");
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->raw_expr, context, showimplicit);
+
+	if (jexpr->format.type != JS_FORMAT_DEFAULT)
+	{
+		appendStringInfoString(buf,
+				jexpr->format.type == JS_FORMAT_JSONB ?
+						" FORMAT JSONB" : " FORMAT JSON");
+
+		if (jexpr->format.encoding != JS_ENC_DEFAULT)
+		{
+			const char *encoding =
+				jexpr->format.encoding == JS_ENC_UTF16 ? "UTF16" :
+				jexpr->format.encoding == JS_ENC_UTF32 ? "UTF32" :
+														 "UTF8";
+
+			appendStringInfo(buf, " ENCODING %s", encoding);
+		}
+	}
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
+	if (jexpr->passing.values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing.names,
+				lc2, jexpr->passing.values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
+
+	if (jexpr->on_error.btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(&jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index c458b55..65a0eef 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -813,6 +813,9 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonItem *item, bool is_jsonb,
 							struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 								struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+									ExprContext *econtext, bool *isnull,
+									Datum caseval_datum, bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup);
 extern Datum ExecAggTransReparent(AggState *aggstate, AggStatePerTrans pertrans,
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index fdc775f..6089ae5 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -102,6 +102,8 @@ extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_
 
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat format,
 							   JsonValueType vtype, bool unique_keys);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 087195e..3858e77 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -199,6 +199,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -488,6 +490,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 726ac30..5949b73 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1465,6 +1465,18 @@ typedef enum JsonQuotes
 } JsonQuotes;
 
 /*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
+/*
  * JsonPathSpec -
  *		representation of JSON path constant
  */
@@ -1535,6 +1547,83 @@ typedef struct JsonFuncExpr
 } JsonFuncExpr;
 
 /*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
+	JsonFormat	format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTP_INNER = 0x01,
+	JSTP_OUTER = 0x02,
+	JSTP_CROSS = 0x04,
+	JSTP_UNION = 0x08,
+} JsonTablePlanJoinType;
+
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlan *plan;				/* join plan, if specified */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
+/*
  * JsonValueType -
  *		representation of JSON item type in IS JSON predicate
  */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 17fd556..d3db5f8 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1201,7 +1210,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1354,6 +1364,35 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
+	JsonPassing	passing;	/* PASSING arguments */
+	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 55eda55..95424f8 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -232,6 +232,7 @@ PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD)
 PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD)
 PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD)
@@ -272,6 +273,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD)
 PG_KEYWORD("no", NO, UNRESERVED_KEYWORD)
@@ -315,7 +317,9 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD)
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 1ecb5f4..9a051e8 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,10 +15,12 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "utils/jsonb.h"
 #include "utils/jsonapi.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
+#include "utils/jsonb.h"
 
 typedef struct
 {
@@ -259,6 +261,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -348,4 +351,7 @@ extern JsonItem *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, bool isJsonb, char *varName,
 				int varNameLen, JsonItem *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonTableRoutine;
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index 4e181ab..d1f498c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -1044,6 +1044,980 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_json_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+ERROR:  invalid input syntax for type json
+DETAIL:  The input string ended unexpectedly.
+CONTEXT:  JSON data, line 1: 
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+ err                                                                            |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv json_table_view
+CREATE OR REPLACE VIEW public.json_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::text FORMAT JSON, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                   
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::text FORMAT JSON, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::json AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "err" is invalid.
+CONTEXT:  JSON data, line 1: err
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+DETAIL:  jsonpath member accessor is applied to not an object
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  json 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE json_table_test (js text);
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |     y     | z 
+---+---+-----------+---
+ 2 | 1 | [1,2,3]   | 1
+ 2 | 1 | [1,2,3]   | 2
+ 2 | 1 | [1,2,3]   | 3
+ 3 | 1 | [1,2,3]   | 1
+ 3 | 1 | [1,2,3]   | 2
+ 3 | 1 | [1,2,3]   | 3
+ 3 | 1 | [2,3,4,5] | 2
+ 3 | 1 | [2,3,4,5] | 3
+ 3 | 1 | [2,3,4,5] | 4
+ 3 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [1,2,3]   | 1
+ 4 | 1 | [1,2,3]   | 2
+ 4 | 1 | [1,2,3]   | 3
+ 4 | 1 | [2,3,4,5] | 2
+ 4 | 1 | [2,3,4,5] | 3
+ 4 | 1 | [2,3,4,5] | 4
+ 4 | 1 | [2,3,4,5] | 5
+ 4 | 1 | [3,4,5,6] | 3
+ 4 | 1 | [3,4,5,6] | 4
+ 4 | 1 | [3,4,5,6] | 5
+ 4 | 1 | [3,4,5,6] | 6
+ 2 | 2 | [1,2,3]   | 2
+ 2 | 2 | [1,2,3]   | 3
+ 3 | 2 | [1,2,3]   | 2
+ 3 | 2 | [1,2,3]   | 3
+ 3 | 2 | [2,3,4,5] | 2
+ 3 | 2 | [2,3,4,5] | 3
+ 3 | 2 | [2,3,4,5] | 4
+ 3 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [1,2,3]   | 2
+ 4 | 2 | [1,2,3]   | 3
+ 4 | 2 | [2,3,4,5] | 2
+ 4 | 2 | [2,3,4,5] | 3
+ 4 | 2 | [2,3,4,5] | 4
+ 4 | 2 | [2,3,4,5] | 5
+ 4 | 2 | [3,4,5,6] | 3
+ 4 | 2 | [3,4,5,6] | 4
+ 4 | 2 | [3,4,5,6] | 5
+ 4 | 2 | [3,4,5,6] | 6
+ 2 | 3 | [1,2,3]   | 3
+ 3 | 3 | [1,2,3]   | 3
+ 3 | 3 | [2,3,4,5] | 3
+ 3 | 3 | [2,3,4,5] | 4
+ 3 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [1,2,3]   | 3
+ 4 | 3 | [2,3,4,5] | 3
+ 4 | 3 | [2,3,4,5] | 4
+ 4 | 3 | [2,3,4,5] | 5
+ 4 | 3 | [3,4,5,6] | 3
+ 4 | 3 | [3,4,5,6] | 4
+ 4 | 3 | [3,4,5,6] | 5
+ 4 | 3 | [3,4,5,6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  cannot find jsonpath variable 'x'
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -1079,3 +2053,8 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a...
+                                                    ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 30b032b..57b238a 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -921,6 +921,953 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
 DROP TABLE test_jsonb_constraints;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+                                       js                                       | id | id2 | int |  text   | char(4) | bool | numeric |    js     |    jb     |     jst      | jsc  | jsv  |     jsb      | aaa | aaa1 
+--------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+-----------+-----------+--------------+------+------+--------------+-----+------
+ 1                                                                              |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ []                                                                             |    |     |     |         |         |      |         |           |           |              |      |      |              |     |     
+ {}                                                                             |  1 |   1 |     |         |         |      |         |           |           | {}           | {}   | {}   | {}           |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1         | 1         | 1            | 1    | 1    | 1            |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23      | 1.23      | 1.23         | 1.23 | 1.23 | 1.23         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | "2"       | "2"       | "2"          | "2"  | "2"  | "2"          |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | "aaaaaaa" | "aaaaaaa" | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     |         |         |      |         |           |           | null         | null | null | null         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |   0 | false   | fals    | f    |         | false     | false     | false        | fals | fals | false        |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   1 | true    | true    | t    |         | true      | true      | true         | true | true | true         |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |     |         |         |      |         |           |           | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | 123 |  123
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     | [1,2]   | [1,2    |      |         | "[1,2]"   | "[1,2]"   | "[1,2]"      | "[1, | "[1, | "[1,2]"      |     |     
+ [1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | "str"   | "str    |      |         | "\"str\"" | "\"str\"" | "\"str\""    | "\"s | "\"s | "\"str\""    |     |     
+(13 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]' AS json_table_path_1
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb FORMAT JSON PATH '$',
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                NESTED PATH '$[1]' AS p1
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]' AS "p1 1"
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]' AS p2
+                COLUMNS (
+                    NESTED PATH '$[*]' AS "p2:1"
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]' AS p22
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                              QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                              
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".aaa, "json_table".aaa1, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb FORMAT JSON PATH '$', aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
+(3 rows)
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  SQL/JSON member not found
+DETAIL:  jsonpath member accessor is applied to not an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  cannot find jsonpath variable 'x'
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
  json_exists 
@@ -956,6 +1903,11 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
 ERROR:  bad jsonpath representation
 DETAIL:  syntax error, unexpected IDENT_P at or near " "
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
 SELECT i::text::jsonb AS js
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 3a39f60..8508957 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -302,6 +302,593 @@ INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_json_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS (foo int)) bar;
+
+-- invalid json => empty table
+SELECT * FROM JSON_TABLE('', '$' COLUMNS (foo int)) bar;
+SELECT * FROM JSON_TABLE('' FORMAT JSON,  '$' COLUMNS (foo int)) bar;
+
+-- invalid json => error
+SELECT * FROM JSON_TABLE('' FORMAT JSON, '$' COLUMNS (foo int) ERROR ON ERROR) bar;
+
+--
+SELECT * FROM JSON_TABLE('123' FORMAT JSON, '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+SELECT * FROM JSON_TABLE(json '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]'),
+		('err')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js FORMAT json, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW json_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		'null' FORMAT JSON, 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv json_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM json_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('err'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js FORMAT JSON, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE('1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(json '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	json 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE json_table_test (js text);
+
+INSERT INTO json_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	json_table_test jtt,
+	json_table (
+		jtt.js FORMAT JSON,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (json
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(json
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	json '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(json '{"a": 123}', '$' || '.' || 'a');
@@ -310,3 +897,5 @@ SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(json '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(json '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(json '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 8bb9e01..bae79cb 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -277,6 +277,582 @@ INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 
 DROP TABLE test_jsonb_constraints;
 
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			NESTED PATH '$[1]' AS p1 COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' AS p22 COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS b
+		COLUMNS (
+			c int
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$' AS a
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$' AS a
+			COLUMNS (
+				c int
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+	) jt;
+
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
 -- Extension: non-constant JSON path
 SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
@@ -285,6 +861,8 @@ SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
 SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
 -- Should fail (invalid path)
 SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
 
 -- Test parallel JSON_VALUE()
 CREATE TABLE test_parallel_jsonb_value AS
@@ -300,4 +878,3 @@ SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value
 EXPLAIN (COSTS OFF)
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
 SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
-
-- 
2.7.4

#13Robert Haas
robertmhaas@gmail.com
In reply to: Nikita Glukhov (#12)
Re: SQL/JSON: JSON_TABLE

On Thu, Feb 28, 2019 at 8:19 PM Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:

Attached 34th version of the patches.

Kinda strange version numbering -- the last post on this thread is v21.

--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company

#14Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Robert Haas (#13)
Re: SQL/JSON: JSON_TABLE

On 01.03.2019 19:17, Robert Haas wrote:

On Thu, Feb 28, 2019 at 8:19 PM Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:

Attached 34th version of the patches.

Kinda strange version numbering -- the last post on this thread is v21.

For simplicity of dependence tracking, version numbering of JSON_TABLE patches
matches the version numbering of the patches on which it depends -- jsonpath
and SQL/JSON. The corresponding jsonpath patch has version v34 now.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#15Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#14)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 36th version of patches rebased onto jsonpath v36.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-Implementation-of-SQL-JSON-path-language.patch.gzapplication/gzip; name=0001-Implementation-of-SQL-JSON-path-language.patch.gzDownload
���~\0001-Implementation-of-SQL-JSON-path-language.patch�\ys�8��;�X����%J�-��O��vow����lJ����"�<|����=�II�+�%?��w�6�7������.��=�s�O��7�#�w&S��GK���=r�����^o.��~�g��B7s���������n���3�X�1|z���h�p�F��~������&c����9#=sn��=����^�&��2;�����o~&fw��\m�.�0/�f�%���]������Fk�Ro�k��:v;&aD=�NH���V���, ��{���>t����,���d4��e�����?�m�#���s'�%��ECfr�f�s�r=����V��6���?`����aA"P���q�����
���7�X�?l��b,l#�r�f�#���d�����"R�a+d��"�=m�p�r�5�=l~���*�)��4Y�G/C����aA,��������)u��n~��\��h����?��<��a��I���
��"S����s��Kv�t����M�4a0�y���[!tx���faQ�����0�������F��g
f �	{dv<h��_�f�{��,��Z��������(<W�	���W,�w����
r}(<=��A@wB�J��a����������#)��?$	�����m�����E�}��� L�� ��c����6�j�J�Ah�`�{��}�~B�Z4�����`��a�������a��"
�
1y��S���y�,�����2��r�W����=�y�B�
3Z?��#}���G������cOu������"��=U���Z�������?�����0'�(���nW�
���Mwi���=�k8�t������C�`����t�������kL�80�Zq���bjj~��G(�������I��vyt�O -�����4'���c�a�i�kP�Kn"��]�����Py@����UQ��~Z�rL�l��/:����L������CbZ�t����D��p���>��b8d��������C��D�P�`~u�ku:��������d�_�O+.6��2���R�����u0pC��I��Pa�QH��0������`�7�s�BM���8�F�@N�)9��"��v�%��]��n���Da�_�9��P3,9�lQl
�����>���Z{h���E�l��f�2����p��
*����e~K�+�t�6�@G��q��G]����_�Bu���������]��>���*kB�`2 %�A���`���q5U,��������6!���f���z��]����Q��]s0+"�-�'��_@��@�kQ� ��A��8�n�v��,�\���Aw���T5J��&D:kX�Y�P�AD*8u�Zd�J��� Q2�>���E��r��vYd�DT���Q�a�:Q�X���<��T@QAu��P#���:�M��&���iY@:n��TTa��Nz:�W�EL���ML����:��3�����Ra��`7���W�t����j����y$�y���������B���D������"&����+��M=��c�����I��~�����R[���P��oU��fM���%e�2e�)z5d�z�1g�cT�q�d��9�:��+��V >��:mBn�m���7 �$����-.��4�$���rKJ�ru��D�f�H�P�$%	+�2�XY���w%*�m�[���.��QR����F�LS��P�D�\���p,�d����M��q�e���R�y�Y����d2
�C�sW��N)�n�85�4�Vk��Q�ny�V*�B�FvMP���d4���\Q�y�c�dK�&�:I����$2
��^��)0�ZR'0��Q�0�I/0���^624 ���<�p�n��������]�������I9�5#Q��DI�L��cRU
4t�[Q�%L@i���Zn��3/��2s�li0��dZ�jv�S�0���BN�>��Z��o�EH=�T(T�����%�'|{{��|����p2�#�m@�C�e.���9qq��S`�h�+8��t����GaF#�}�y�����k�3�j��)c����*�%�N� �9+?CRc)��e��7h��,#
5��Z�3�_�f� +���M���_�M������H������!�l�{������b�:�vS�))����wc\�&�Y�v�><�{@u��eh`AV��4\|����
�-��3(���'���OO�d��2y�s�"v�����������VF���g��L�9H9�}R�hk�u����� �������$�g��o�o}#�$}0���q 4�CZ�@�z>��	fI��\�Ng�O���>��E������7���M(�[�]|�v8-H8����k���F�6>I��d��xc��)���0�_oI^}=���+��C<~?���|���������D^�����jy}�������u��j��|��|�:��-f�p_�3�if�%7'$�8<��*<vX����V�h���@�����!Bb�6��[���=������.~
�x�z|"5W�0��h�I��=�*���=����`+56��Cm�Pe*����R������O>���l����g����n��CH���k;<�k�o�����"LI����a�E������^�t�;n'��`�Q��s�h���{��l��	���?��K��r�SI#{'UU������"��u
�5�on�<��}M����w���D~�TU��A^�&�����q%|`��y��8�pq��������C��^�
���f����8�Vyu����na^��z�Y�L���-�l��d|q�����^�EF�
�W�
B�hY��4���Wi���!f�6}Xd������@��O J0b��!wl��Jf02`�Kc7��5����*XN�i�{1g.�
�;�����-�oh��H�gM%[�����@��}����0�Z�'��:���BYZ�HUS���C���SY&���������~Q ��,�+r��M��7�
�6p	7��&����6�J��k#�#_cl�����Llh%����JC\��:/��#;�TF�����x����������7W��77�'��C����B�hj�������w�{f�#�v�����
���H�m�%&�M����:&P�:&��T�1��=p--{H����1�8�y
!�YF��Le�����k�!��W*�<�A�/p�����Y{�+����s+^���|����-��/Q`x]x`�	�!D����	)�����w��H������l4���0��������Z�����h8�`�%�1�"k���ml�S�ss6��u�7q�L�~<���)^�\#�����Q�1g���3>:��Y�#�����[f�=��.��pc�YW�S
�����i�������B���(��Gq�E	T�j��1��=9�&]��!	����"D\�o�YW_W���������w$���p����M�<�
?Xuy-��1m����r�NQ��v]�7�������������������3'�|{t~���
E�[�DkC@2�9-+������{TW:8q��B�}�V�
e���xd���	�)�6Xg
����&Z�h�-0M�w ��7��.���?G��xI-�g����?^��������N���9=�O''�m���3�������2�9����L���h���n�?d��o���\3R���}k�u����bs��<!��=�=��h�6�I������`����B��Ny����q?%E&������l�c<�����l���������H������
��%m<�Ax������t<h�?����t�����90����~g���!�D��yg��HM�Q��(Cn�$�I�x���7���l��l�N���mX(��&���n)��L�0?�K{����,y")��X8$�%��@F ��C�4�sA����/���������/'�%��~f�Q��C���#�c��
++^�f�g���'IFKI��d�7rs-�#�Tg�|	��2���t���(���8�m���+a{q{�-���[r����#�oF-���s�D���h�.����,_Gu�
�F����0�����"I���6������=O�c�\o+`Y,��jG���~������=�.�����*�Mk
�����
wU��
��;=��+��/�WuO�Q�,+�����'�Q4�O�Z��e�{����b��-A�O��������F��9({��el���A�Rk�k<s�=�HC����\?�;��i�CP��(���KF�B��i��*�C�������hP&�y1���-���Y7������� z�!��F����K�����b������i�:�����s��8RR�<�*�z������#�cSO�����7�������`(��Z�u�O]���HL��Q�S@��93-�T�k- 
<��:�GlQ@~��:��/Jg�Cy�y�����>X,o+�����5�T#I�Er�e��pM�-#�p�H�X��I>��8x#�����Lx���"���Yi����i%����Xx�2v�����G�q���|�0Y�>����-�@^.Ld�R;O�3*��x��"�*�6���F�C�(����S�c\�)6�Z�2�
�-�"�@���HKN0���r��
��GB�@^�9@���d��Z�"0�O�[.�udL�@ut�?��y�	���8�NV>q�/�x�����30 ?�)�B�P�$<�j��PrI�oMWjL	�E��"D����<��s?�VFl��O,>�#E�h�R4��"���&�b�nK~�����{���^���]$|�p�b�
;�!Q|��YwX���[�#�����2��l%"\&����@c��������3N��x�&���C������� �
��G��9���������hn�����&}��v3��XP�����f��Y�jz	Y�?��:�"�����/S+#T/VIM-��P��d�Pn��C��q��Km���;�S����cjO�LX��0+�R��Ib�N��be��^�������@�h���N�1���#�dD|�F;1tA���HN�D��x������d�F�o�"yo�Q��2:mC���c�G#���T��S�~�
M�P�I�AFe!�����|��HAhu�� ����s��
���C��%�%�������_&�L����5W�#�'t��S���f����U2�G\������R'��jJ�t�+�]��������,��'j��']���"�L�>��2aRHi�x����E�|c�^�����;��tf$�b�mh��]*Fd����([��0�i���Xx?��aCwr|R�o����bQ����zJ�3�+��AI�yZ�"�L����o���aK��H���;�}�J+0��*?�N�����w�d��I�J���/?]f��|��,8�*nJ�dA���K�Idk�����`8@������w�z�P�����
�G���Du���u�H�2�;�boK��6MQ�� ����'��Y���H�\S$	�y����8����#����@������5esu�s&ap,-uz���@%�T-JF5+|r~"�C�,Zi�����?(�n:��#���x[��
��J���CA���? ����`�����U%����{��6��Q�o�):�� 	$v;G�&a;HN����w�P�-��M�����g4���>��I3�VWW��Ur���D��Kx�3��Kj��u&C��4�a1�.�� ���c$��Vf7q
(���-���r��%?��X���r�P�S����;Q��x|5���Rir�r3;`�<��^XF"�C��;�E�:��S�K�4�q��@`�S��E�?B��y��
E���)d�*)���2��$OX�#��
��-4����s���P�v�y���R�L�%���	6���D�E�oQt/%�(��HE(��������������������`���I�����_*���=�nyc�����Y�0k�
.�'�ux�K��!l6h	�����]���BN��U� �&)`$:F��%fv/�8� p�?�xksD$�)0H��z
u�9be��[����)�����+P�v���P���]�����,}9�/�Jtb� �^������;�>`r(��B�::pdT�ki�0H�R)��&���[A�����E)'����X����lJ�o���+R��,����iViU&�cC��b����nN�_�ci���C�
�S���T��7���/i�e>4�eg��>�����C����`a�n��l�-)�a�81�&���4��X���1r���%�+��H>���-��'
��k�����W��g	�b���n��R���d��)[0U6�#9��
2��S�N�]j��Dt3��V����NB��lCYIH� �~w�`��:;CS����J��c	/;N�![����x�>�c,��D�p"!�S��X�������d��(���7����6J�E
f?E�u�	:�f%
�![���6��Xc�GG@�*�K�V#���K;�g���0���j��}�D��;��<���A�$�	�t�
g�GQ�W���~'�\�Y�&{��OD�:�Hc&T�.e�r�it!V�
Txn'�j4�-�(��VL*7X��'w�v8Q���p��Fi
�.Yo���a�}��L��#�k)��v� ���������}O��P�Gfe'��ez#��3:z�Y+;��Ov�_6��
�k�#��#9�C���4u��S�
3a4D����AU�>����j�$1�G4�t��nP%.$�!�������+z��%���p�J�d_��,^��}R$�p4�N�[�����`���R����V�f����:}����4�,A����#P/�����<q��^0����"�7��Si����F�H���p�;���"1���C�&
�(hn]hx�;�f3�S����R0�lYk�5]]�7��[H�F&6}���
A~������I�o��0����uVo��&�'�;�gU�������C���;y_���B���� !$��J2�I�w����vd�b$���5��
�����CJ��PLPA�8�������Y�R�-�`,5����}���������.��Q��pLjEi.]��j�j7��L|�3�3�m�?��%>���$�Z�g��xX�l�����t>��cd�m�6���"����P��9�W,����(+Q7&�Q��o�c�������aH�>�%���d\���H ��p���b�X���,�Mv<HO��1�;��*�w5I���j\5,f���7/�W��P��������{�Q�����b�[O��?�et�� �L]*��7vF!�L-uNX8�^@������a�v��5f�X(Y��4����*��n&��U%1]&�I�2���1|Z���T�R-�lE��Q��������s��03�
��|���y<�b;���2��w�4X����3\Kw�k	�p}@�:�z���k����#����\#�~Y��N���{��,4n.���`�����uSn>0,����gO�('6�������`X���A������\��i�U�������Y�a���3_��i��dS�/���P��7E�
p�M��JQ,V����9A,j��j�,C��V��X���`p���t�iY������>��
|���_����C�h��C�������>%����vi�����3�z1�m/V���s�
j���� �E���G��q���@xGc4l�j�
�+��8f��$`�%���H��$4��_��>'$����� a~&�`�n����w9+\�|��.&�v��#Kw����?J�����G9�Hu%����\�� �}r���N�~�&���RO6��?��s����b&�Va�du�,���v���C�����ML7�^Vy�����w4=�^�J����Qe������cVf����������8!��53��_Y��p
�8l�?���#���v����@������������:����-�l���]|K��E��!�Y���L�V��E�1�<�F=VW��IB^���f%V��c�m�{��(�@����vmS����^�����r�n�)$��q�G�����ycu*�W�����{CL�>Z��U���������9O����
=���z��b�3}���]j�j����oWm4�$=��
?��H�A���������{&���K3��(0��4������Y�#G���j-w>*��b�n\�%����CwF~���t��o���ya�=�L+�`�B�@V��������@�9������#�}%��E��@GT��}�I���l@
��p�xV���`z8����X7�W#����y�}5?d�K�}6'�������W"0�{��N�$��*�i!����Et�G����yX�O�N�gG�H�3���apN}��&V�p#��`+s��3��pX�ZP����V�Fq�%M���-)�X�B+�6������8�����~bs�KiU�����g�.v����x��k	��BRB
Q�n�R��D���n����y��vr���Y/�����a�'$��_:���s��y�=X���Bk>�l?��9\NN�_0_4������Z�<��D��Gxk<0wZ���6�P�tg�	�2���EIVt����}�3j_��,pG�33��'�(/��e/���9u�j����o����k��:��������5�������	ND,Y8��y,}N	�hL����S�c@�;.�5{y���8��lE�f�d�����xU<�b�e���4���B��R5��+sz�j��e9OA���ux���Q��A�.�PD�;@\]�v������k��"�6���jz{7�?kK��o>���?�y�~�7!�WU�
E�����<Q������y�*p�F�_�P�)1	�h�4C+��������ZN���^�X}N��&&R���DmS`/C������[Ag���$-d��)�J_*3$T�t�2*��P$:��$eF";�~z�����$�	���[�_md�[#�����*��)N��<��3�2���2~s!c�_F��f��%��I�Wv(Rewc���%�M9J)��DZ��`*0�&%0�3����������h�*��?���(��4mH��	������L�����������������E������6}�d�'O��@����r}�[r}67���������	�����(��L�������I���G7����r%��3W"�R|��Z��
y���P�R��dNC��FB�	��5	���������`���AN�_)"�V?��r1�g���be�a�[�l��������Fi@A�qo9?�J��='�X�G��T���%�=�/>�I�Lc��9��������{$����*�k�J�H�����fq�Wgi��V�[��������Z$�U���j%���B�f��<���]�����GI<�T��������.���MK-}�akL &h0�r�;���*L���f��6�74f\�~'�|]���
�$!P�M�a�^{ P(��q�}���Y��<6O1�+
U$2�Lh��e���M�XV�1G�Q��Ls�\!�F�A��L��!s�������c'3����S/,�i�%���~E������+r��V������Z4��[&��������3�k��o0��D����d/N��y*zQ�i�m�h8v�����hS&d!�)b'�D]��>�j�]�M|��b�n�/bq�F�7=gGc1o�;�N�������hx�a�o��d��`6
���6�����,�3���X���������H�3�'��,h{S"�F��zh|k����C��[������Ks���M��r�R
q;��]�!�������|��a�C5Ft.��*8�y�U��
�3]��^���P���������Z�&>�p9�������o�o��%��0��l�^��R����|�^N�D���u�����nd�������`��jOaOTc���5���O�<���c���5����� ������KX��"���O�n|~r_����f�;��j��'�������	C��|\�����	�db���6���w��Z�l������MD��wM�)���J�,^�2��I�irV^�Z��'��eB,'!�������{/�&?J�����h������?�?�p��W���{����������8
zF���j.��d���g��.d������l�L����v�x�0/�k�0E_�yU�"x���~���,�\�Re�quwm;��I( o����3$6�8Gc�Z�>��_2Y�jd����v�����f*�q���w���p$`L��
w1�`���
�����u��������z��jB��B2�0R���RR�q���R�������5�3�UZw{%E6��O�3� aK��2����'EfBE���'G�{�MPwE��2������aN�qQ%a�����L�:|;@b��;+�������<�&�zy7���Mp��lJ��X}g�yn��h�1g�JU/GWWc4��RY�/�!��J�o�7Z��vU?���t]d���qGm��m��w�����������a��Jz��+��T����{i�k!��,>���D�t��v��������V���2~���H�*���v����vtQ���������#�Z|�����*As������4�Q�+�y��%��z�O��o�����3����uOLc�^c�t���l6�����(ypA��/$���[;�Q�\�����F����1/�UD��K��G�V��D*����Os�����[J�4��*�G@Y���Q�S$�����E��4�Q�D���RwA�KtP�Q��2R6����
�3�T���!��D=P�!���	sdt'};���W1���%"�2�3��:�q�!w��X%9������-���vBs^6�g�	�i��[`�����y��7��bdc���MZ]J�|�+�mw��-�b��?z*���R]?2�U���s��^�f�D3v0�
�\cL�NI�9�I�1n���=6 �^���W�n+d8m����Mg�q��n�hY]_�K��-����b��LW&��M��1>���0�1g��G�i�;�t��<n@�wjit3���N����B.�<�[R~����Pn���noZ����4��qZ��l5G8s�p
vc����r?���u���2s�,���,���2�X�Z�*V����
��{��M��y�[��xy~z2YWPwz-�����FW�2�����'1�NX����D��2��#`�������b�Y$773�l����r�������Ii��13J7Q{��L%_�5I��$��
u������(&+�u`E������IN
��G�71��d���;����=;��������,��l���Q���
����ss�"D.Unt�/������s�{"3'm3�Ha/o�bL�+Lx!�2�4r�����~2�!�����D������I�=��xbs�5+�������2Y
"N����~��i`���.L8k�-��G��4���rQ�r���4�r@p������J�kIr*-.����$g������&MK�9�M��O�@��i�����8���(:k�=h}?�H��=C�	�+wL0j
�6H��)�%c���!{�U�S	%�`��w���\1��L	�`�
�)��(��V�+j�����V%kv��
[(XL�N�HmJ����������Q���jS��J���'�Rt�rk���ph=�L�H[��K��rb�?�����c�Mf�t�3��C�S�����2F���%���!U��������C*��"E�)r��!��L$�(��(�d;<]�9�K�����;�����"�9���6�0�1t��4�<FU39����V�?�"bt!�'E�u�yr�U;��j`��/� �����r�$�wK1��]_R�S��Q���fe��2H�,6�^
���!��4��s��P��*��uo
WM�<;R�c��Q��9�|�q�W��i�����
uj"�{���5MH��)$zH�$+�?�
�� �I����]�,a����S�1dv(=,f�e`�'����I<��3]�=��y~Vk4O^}���v�2Sr��v��*_�J����)��=$V�K��7���RI���l���+�bG�e��IBb��$M�3j'<���<������c'����v�>�����-�~&|�,a�N@���!M�g�Noz�k�q�����{H�X��m9Ieb4N�������1u]�	GY���w�$x���'�D��!�J��Nis�Z��%a�o�Ocb��S�������(�=/���L"��~���:�h�qEc�q��������pw�����T�G2����7c�����B���<��LP"��	@�?����b_��4��5 &^��
�8i�����o��E���C������R����t%��A2��5��	k��A������t��E��!���@�O�R.��=��
2m�h2����hWs�EHT+�fQJ-�
����t�d{�5a�,4�-O�E��S�u&���;<
���e�������h7@`��(&.
aY3n�K�ON��g�Xj��]%�n����%.�U�4:
.�w:������0[���p��h�@����z����"�X��7�w���N��^��v��\|�"�����a�����.����0^E���S���#2XFW�j�5^�}�S���	u��Z}��B�^z���Gb���q����(�;%������.57S�OV��tU1�-5��W��V��t1����L�NI�7A�R��h����.��8&Jps������B����>�������z��r�� <u'/��Nw2Qf$<;�Bir�G9n����[��E���L�����#Q>{}z��i��	F�K<|*�.��B#j��/���x�A���z-�eLEx��V���e�`l�0e���b����W)���P������'_������'��j'~��J]���}�������
m���be
en�<� 0,87�h�	����}Q����@��y@X����I��$��Z�h��viQ�q����v���2��V�OM����������4��88<?}�}c���A���dB}{yT{� �Qz%Jx�������������C!����+��)2�Q!d�dN���l����
���sr;h�#�V�����B&]O��5�����t����7�-��j�;i/\��1�X.L�t�w�������u}�\��+2Ja?��������O	������n���"����Bf��f�����H��S[�'(�yI�V��q�����'��<�#���m��ju��U.oF��et����6��uR�r,�*;�ge��k�j'���^���I�~~R;z$�����8<>~���8����y���~$���G��O���;"=}��$k��^k����8���>/���7��0�m���8����9B���ORr X��0����'����o�O������Wf�y����L|e����G>����i�������_f��z��%7�3�Y�e���y����@�a��s�f�������B����bx�4)�I>������{Q���)��}����x�# ��&l���y.��I����������|d?������\6��?�Rb�A�A:��I������1�d�k�������
n�I�.���
�������,.���T�\oz����R%rN�������,����G���.�q����`l�/f��R�v��r��^.�oF�k�A��j#)��J���������[b����8��L�i�z�~�r,���,��Mo��f��1X��d;j_������yI��!��N��A
7k�-He\��@�V���9�����+��S�J���a	��|]]�3��%S�;��$�Z_���E��;��&�K{$���aX}=Z���S|x8���A����a�q���4� ,��`�?�3�pp9D�gM(}��� ��r;������z�V>AI39�=��u�x$&�1��&>�}&����,�G�6��.����l��{���2�=��*����f��rK8ti����C���#��"�^�Moaia�t�������Q�{�����A�����p���L)��S^���V�.*��rBK
�o��H�����5e�g�z�����zYo��n��i����V�������+�����K4�%����?B��kv�m���n�<ne���T����n=!��]�����HA*������\,���pD��x�X�F����5�cA�����p��q����\F����p�3�����=��xMeD�n�-�q��S��>�*UX����X�lnH��C�68���	K���G���.en���-]
l����eosm�R��.�t)uK��[�^��W���d�3�_���Ov5c��2�_)��+��&������<�x��|���������U��6�x�mm�t���SR��O��t�N�6R�����fl:9������x���l3�X��n��j��[o�;8q���Rn�9N��mQ������%���1R0��4��������a}�	&c�}����x����F�n����<f���� �=/����v<�W���>7����O�o�$��a.�q�n��c�0)�P4[��Fp ��f�7_(8��Vcr�7n
��94��x�>?qE�Pi�M(?%��^5��U�N���XCTv@�^;�������w%:��>;�su�(�b��E��F�h�*9�>��������]�U^�3�,-����V��z$����k��8���s&kyKwmf?<]����~���*sL�=�N��������1_ E}LJ�q9���Sq��F�9]���-m�*9�{znt�U�f5|����mE�,>l�q�N����)�1�$�r�������
�xF
	bY�����E�6[�A�y��%f�J����]��\{�.����@�V5��N[����������/X����F��pI�\2�������F��Y��p��fd_���dO&2N���G��wO1��!�Fq�������t��S��(��	��_S'��e�j��b'���p�����E���D�C��@�.����>O���R��������DAr������`������ot�z�����k�C��CWC�o�����h�������1�
*-j�?K�e��t���n������
����3#n��"g�(�Z�������m(������n�*Y�~�7=c
Ys���|��
^k�[�l����b���KL���d����d
0�J�E|LD��WtdyYSs��T�.%y���r�?�	����(#��F��6��{��8e��6��t�N8���Y5������o�E���Vh�����5����:T��!����6X�=�����Y&Sce$.���:�N,������]H�E]D|�	�lV���-��l6_'%H��������C����i�
$Gy�?%)2�
�
������X�`���� ��N�������?1�����ftE�0�i~[)I���SUN�M����nu�\�.w�6��vS�R��.K�������6T����R�_�Z����C�v��g0��1x��F9���Zx����ZoqA���`��"�x��6bx����t�Jk�A�#u�V�~��/�Kt��:�����T�[T��_��������}�B�k�~M��~wcw�`����71��;99�P.a|wqO�z�*���� ��"m��>���h�e����S(���I>��jSJ�D��$�X���|�bc�N	V@j?��5�-R��txrp�S]e�����gG�����9�4��2+n�"JV~����-��z�~~X;:�w=Xl�{������fk�u}��V��U�(/�W�&���Z�����DD��p(����q�p����t�H�BBvx����N1Q�!ch�6�3f8*
��<g`�-�f����v�"@
����sz��XDv.e@����gLe�Z\+���[
��S/��-C��>6����?v�����uG���MJ��z��7���5�0��W~i�l�y��Z���P*~����������/��a�Z��o�{Y���BV(���]F,���#�4�=����5-����ei��OK�A��]4�Tg��x"2}�
i�y�E�u�����V����6�y�-���^_u����fsq�*�$HC}��~�<�'_P�������t�cx��C��[���E�����������GuJ�������j���;�y+�[C�0����Q#�6{�WG>�i��7'?���t��[�!ET��-���%���*�'z�#�Ax���q�D�d2�:�����K�S���{��r
EW4	���Mz��8s��&��
	��r�hi�-jc�v�	
�j�����l�<R��L%\���@6b�����
?�����>�kovi��������n�(�[1 �c�����P{���cX�kX1��\�r��3~����+	z��"<���]����-�6����Df�l��`�r�[�)���W����������_��OO��j�����y����^�����A����Sr<�ri�e5�$�t$&
*-lB-�a���[@Q�`t����o��5<�db:��� ]���L�f�=�0
`�::�`I�k���4��aG�i+���k���XpLJ�q�%Sv���������)���h8��Iz��f�u�����5k����8=<������1��
f��p�	>�Ba�)����`����������)kCv�f0��(�<`��c��E���G&Z��I��� ��Sj(��n!yI�~�����h��!x+B�'�G�m��(��b�C;)����,\/��<ir���
��8�E�gF�+��T�A�(�fP1��Wr���4�k�8�P[����FQ@�=V�HG�*�h�W@����
E��d@$�D����%�{eE.�5r{�%oV����!�F�L40c�(������4a�P���]�>n^�9���p[_�?Q*g9�5����r<�3�jf!�*����4a�+b�7����i$��W���n�3���9F���zI���1W'SEb�<A�)���srao���[����;��Q��b���t4�h6��4�b����eM�L���f�,4�wfiYxy�����3,?�v�I���.n.
������f��S^��JAM��Lz���Q2%��]�L���&����%f/3�v+��A�bz������=��L�t�d�6F�W�{l\K�3�& vS�]�]nP��l�Q�h�g�g�L��A�
�3[e)�n����8�B\$�zv��\��Q�1��`������p��@�2��UW�:O�:L�
���~�=�P?X7��I���i��zg@�{���D��\�F?�����[&9��	u,���n�yx��	Jf��kd�Gf3�f��,_K����X��Qs��9
��
�V8�hb�����y<2)*������v$a��P��vO�'|0;��jfb�g~vq�9�o�+��/���F���"p��(LC3�F����IY'��C������P�s
���x�4�FH�aq���X3	.� �Z!j���qsAz���`y9��W]����1�������dF���1�B�ZY?���2�3��t�CO�����x�W �	�����z�\�U�y�~����
<��+���L%��QFB�{�uI�qL�����1~F�A�)A�wO�7�v|��F�C6GS�y/7Bm�7F
�"/,�����d�J&���#u�����0�f�EY���y�lCjU���q�P	��A�LsX0�Uc:{�j���&�O���
�����qE���2�4���~w*�"��f�E_w��>�������4����$Y�3I(Z&TR��4*�~����G�v�������������p�����B)9��������[����������s_�a]���tAPk`{=t	�
:)\����h,m�_�����=����
K�+�J&�t7���
n�S;z���6���������l4A��@}2��^���mC��Hf���^]���+�/t�w�VZ+e�0��\U*jPA�5�C5��h�p��<E�V�����i��3�������2��M
6��HM����q��k��T4�2r�e�QZ(^���`D��Q�VW=�t���J���g�iL��_X#�{�A����������I���$&�}�k���0&\����������0��=�.�X����|C(X���D���!���	f�g�o��)iq��F��26�-3/h\w�9"���g����}v���i�j ��������[_LE��������wdK���l[g�I
e=�V�]��,�3�J���B����J[��c������|�f�c�HY����1��q���?2<�����6����&\:}�i����-���F;��J�@_��c602�[kb�7���c��1�[�Z�����Y�C���)�]�P�<��D_y��%�D��r�k����[����B��������^3b��i�g{8F��3>x, f�h���D}��S��\Z�����SVp��"��6Kzk�]Zc��=�����M.�����C��R�-��W�I������i����-Q�T� �e]H�4�)��DC[������EC&�JL{�B�D��=U�2�vE�"�;l����>99m����Md����Wu����nW�`z�21#�'��be����^�<z���]Z���9<�,�Y�������g�����e������=j����7���8�����Y���?I:I!�~&dm.��M�c���a��p����#���=���=;|&���f"\)�&��������c3'�����Y�X�g��Y�<:�hR��}�R]���-v.HN�Z�HI�������]qrj6��
z/:9�A#�gc��9Y���$W��A0�U�����l
����kc�G�F�2 �����zc�!�Q'�|g�=������xMN
ux�?jtx�e�u�q���|~����5(���Yv����r9UW�&���v)j���s�2
��+���qg�i|�`��l��C����UlH.��v��8N���T�*���N�#�����|���L4�����t��z�:��3�C4��Rw��8���534,R�2�bD�%�����*���H|;^�I���\f����<.O5���P��(^�&E���_,-�<q����>�����C8?b��TY�e��Dho�nO|��"R������C�(�;Jhl���_�D��GF��O�ru�5y�_J��<2�-n|:� i+�-��T��/,.u���1<:�����1,1�4���`��������U6�Y0�����W_����E}������:�~cm^�0+�D�,A��>��������c�c����z*g���m��5�Z�);Aw��~���d<f����%?���{����b�q��k�qR[���\�*o�����P2��da=;o���H|��Jm��&�����z�$�I�3L���d����A���'ey�2����C�]�������NW{��}�?����=����^�������������n5�
{Z;��i%)���:��O�\��Zm�HE��_�?:���B���.0�����X�_�K�N����=O�)P"�������-���������o)7��A- ���5:
y`����hr�E���4{N��������-�f�q �^�~\���n\��q���m��~����'��u��
NX���@��H��j_����b������go����a���]]��1@�o9���(��d���<���A��u���h:1�����-KQzpt����J�8�)�bg�a�S�`��l�����ad��CwPK�0�t���I���E�C��706����M8k�2(��,@ ����^7
?�"�_�^`������y�� 8�����Z�����Z��^��9E���^�=���>4��[�x�����C���m��0�W�4YAv�����c�y#��H���N��p�b[`I4r�_�������C|K&���8�U���r�\�����)}���M�=I������w�D�ck�vYo������"+;	N��ni$�b���R^�����;Cm�.�V��)��$P����PS��y�LU��3ac��]Q�7�s���!�`��+Q�`f�KzF)u�s�Z���9�	�i�^6	<M�*�"�&s����
l�6,z���{8�[���4g�b���"���[o��Dr����a�k��#���
����#{�d��1y����^�p��U��>�4��@���W�d�Sk�VIo����)�
BMC�k�&	1wW�r!xe�iU����oi�W-����2�W�bYuBKf��Z8],e������KQ�Ns�	�������4���g��9J��4�,��\b��p$'��t����v��"�8�Gj%�x
s����
6��&�b>�`���A��)�~��	�[�����R�Z��.����E�ma�|2��3�^�;Ly����`�����������W���6�N�P�4�z�����-��;y38�������u��/������oSj�k�����J+�\b�/�V������5�/�i�*2/����)\Go4���D��@�'g�������Mh^�[�<�7�]��~����g��G��_��Z����]V�x��)`���������?q�/e�M���� ������"}��"���p�l�\�����G�:���w��#���2�cg����P��/W�2�g����z��0��|h������-~�IZ����T��t%_�QI�
=��R�<���X��?L��f]Z�\��B����	Z7�v8���K��d�!=�a�������r�������8sB��C
������gTs�r�5������m"�%m���RT�5����2����,�E��jWW�m�hfS�������Y�h�ZZ;F���)���l�(Or5�.�2���uP��e�;s4��d>0�Y�������Y
e5��>pR7l�Q�sZ3���L���@���R_����>l2u�6�����������O��,��������^c��5�������\�������Y�5Ni6N!r�n����t��A��(��Qq|V;�gy��xN7�B��M��#fp��7\(�����6w	N[N��7^��t�99���SN����	��V�;�n��%O����
�T�
(�(L	�@���N1��NJ'��N��������SYGh�Tv��5^�\w4��K~_��#y�-��l_�GGw�=��l}@���p�� ���jr�����������gz^8�7����v��S<��g�Xd�c{Y�*h-BD8d�
��s���;BhF��uK�_Rg����Q��HR��O5hSs�/��������LgI���%[	��;[<4>�>(0�����t����{"
lY���F����F������)2�	9������Y'{^"�H&N�,C�{��w>����R��x�bt�F��1q
��1:���e(qp�5m;b��kJL��� ���U0��6+�Ho#��h-�X%E�hLo@���8�:_�rB��g��n�����V��{�u�����aw�~2n��h��N��,��[a��&g�4C9���j7s�����~I���s����l�d��S��d�a���^�_��v6�N�\���������~�[H���eHNf1y�2M:�J�W~�����&�g��%��N�M!3noQb�����%�����77����}�<\��1�u�GEq
{x��%�?�'n�7�=�/6�/X|�m�������+qr@`�+(��'�(l�$���h%���u�w�IiK������������Q��L��	��3nW�p(+��I5\m\
�]���nu���,�0@��(8���e��:9���/d������
�?��)0�K6��h8x�A�� E�5r�i�maW�g��8g��s� \(����LR<�Z�	k`[]�,.��F�o��'��7��;{��V���V�fV^��U^�2P����O~���3����s�(��GNT(�O�7��"�|i�e#������5����x�_[x��kN� ��
���T�&��;X��sh�e0AX�s�_����,I�"p/KmIR�`;��!a���m4�w)��hh*�r�Q���k+@�\�f;
Tr��XI@�+
��A��W|g�	�
�	�{�'������Z�\�T�Q���'�-��	v���Mb�U�f��j�|�Y/j����N<������3GC� �r+�j��|t-��������U��������������<=Hn~71��$�1daE�C��G�#���)G�+t�%z���Xt�P��:�v���x���x$d�����O����[%���J�R���?��1Go��O����5]����7�dcV�w@�YR��fcY������T�ag����12���3���nw�U%TS�����0��F"�i�R�|���D|�c���
Z�X�=Sr���\��1�B��YZ;�_$ry�)���u������ff���BZ�g��=��_��%��A�*�
G��l����Bf i3?(��%���;���������\�^T��w�	<��x�AW�?A�wc$F;����:
���F��\�&9�X1��m������������o'�4GP�����V-Vv�F9�&��$O�X��?�����-~,P�BWe<�fp��(�������gf65~SjJ�4�����M�Lh��/��!4��t\j��z3��N���htHxe���P0P�
n3<������Fx3x7~��eE�x��9���6��l�R)nn+4�P���8�[���x,W
�(J�z��p�P�cU�t��Xv�g�l|+�Q.�g�7u�t%7�L�j���:X�����d&wi�#�wk�5��i�� �dr8��Q�����hc`s�X��$�����%h��[S&������iMP>pP��
rar��b��g��P���O�r/w��PL���{}iv�{�0{�:�����{���?�W�����}�������;�F|�x��%>���vw�Z]�(nm�����4��-�q�q��:�����;���`
s��_�<�5��TA�(����rL�3>~��5����>���!��{�x��g������9�k�Y�5��>�K����idW�O��`F�����xGLJs>����W5|�d�61�gf���L�$����B6��\A�����}W�w���bu�1���7B�7�/M?���R??`&��Yx'��F�6�a��Q�,N(��k�����Q�&7��G�*+f����Wf$��o@3C!i�f����5��E!f)�L�-�����
b�v+;�J����:s���$����MJQ�q����������4��[����+x�}-�X��90�I���E"���o��+�hfh,��'O�yE�w������`���5%;P�o�Q�gLk��c�<���&.�=�{���51+r�o����4cZ���=����������
#w��i�jE�Ku����LU��
��GP�s=�.��qU�,�-��=�[97ka��-Lt�����0�}&z���"-��c���-��%���������zg�]&
��8���gi"�@�UgF7	�Sz�v�G���?�����O2 �����m�)�J�UIz����,87��.$��,~���)�qLa5����~SqCqXS1�����3�0c]/�
��7�P����ca7t��yii@�Z��*�-t�3�.DY�3�k�u����V�����v'��x����@���U�I���>�V>���1$�.��u?.�����a�����/��4SBbp����c/F;j���r��q�����E3�cp������Jec���Y1��b�ad��p�d��
���^���`�^�	�������1Xd������}�!I.HN�Q/��~���B�p	�X�.f&�"?d��7�� ��A�E��n����������f�;�����RN��}:R}J��1�z$Ww�S��^X�3��F`��Ei	MZ�K`n����Mu#:���hQtn�XUf_��/���W��ce �������Y����Q�}>`�^�������V���2�~/�'����$�.S#}�f q>�M������NGa���H�dh�d������j"�:h"��	3��wo���(:���
>������p �DQ7E����OV<�)�cQ�:p�h����A��qM?�����x��'�%d�	�/�������'��g���7R���I$�X�$�L,��K;�D�e�d(�D����|g"H��N��D��X#/�A�*%�l�Z�F&�a�<y���j�I��x�/�
��i��>Wu�B�m�����~�t�2:��1��m����p�^��	�-P����Sve!����d��vV��q�k,$8�|�Ck,��^�6��g^���B�*��W�cb!L�R��HF�3K7�i���3�{������ju�\��U.v6g���[HS��ep/lq�D�`YH��=b�y�v���w�z?[�(��e����*�<���^���M�����a����8��X�U��%�N)X����W��'�+w��.#���5s�hq���G���j���)-�?�,%��H@�r��W�7h��=-�5<��*B�
����<+�o��l��_=��F0��&�8C�I)�!������
W�&�3��_<Tv������}3k�	�l���4!������|�b�C�W���9V,��	����>.gkF|tw#	b���$��"�����I�MhD������}1�*��b�&$��LEH����/��A<C����d������K����n����/K%* 5"���7sL|�T��Yp������$�KI��ct$�;[E���8p
)HB/�~#���GR����Ck�Y���6K�\H[�`~2�f+N�g�(;<���c��|P$Q�!V�ww8�@uS^Z���a
�f���CK��"ph��������c�@�p\k��.,�����HZ�k'����������.�n���H��]c!4�n�jsuY����u
Z�f���������Z�n*�Vi-���d77c�J��c��J�O���B��3f�=�0��	��q���:�[��:��az&���My�:��b�\�n��w1�T����~��x��\�j{8�N�gB
�ZN�c6.v/��z���q�io���c�[J�e���E�����6^��
,��h�� ����nKx����8����V�����x),,�?�������xEK7��~���%��	�j�Yv�J}���ZxXR���,��OD���^��3/��������� ']z>N�^���f����3���������V.$�@���^t3�����bJ��V�X�w������z;#QjCY�%R��~'N;nutE���6��o,��K�{������4���5���Q�{��N�Q�����K���-�|�+[Z�c�2�����������	o��|��bm�c�	@R�B-w'B�W�L�K"�����8��#��0��������&�At_a7L��?����&�UG�����'q��4n.�f2�	��7GGr?�}��a�@'gp ��kGG�����F�e�u���#r����G`h��u�~��Y��x���
���d5A�g,f��{�
9��-��Uo2��JM����|C��2.����,�*]������R�S�B:F��$�(j:)<�J|YX���:��2(��=���i6ve��J��@6jc=����E���g~qT*C9���g���~����i����<�� �"}�z5���[�p���f
��5dX6��v;������<b����
!|��\
Q<%$�L
������F�C�q��q�� �|�=�u�	����t��@�9	P$����j���x8Rj����	g-N��AwZ#��0��7.�Qjac����d=�������bh����oTeD�/0}-
�|��LQ#���������9��\way����s;^�6���/�}��
}�X��j/�*��4`
������H�DK �P��T|C�E�?�1��bH?j�wN�Cn����p_�r�
����uKU����q/�����+pfJI�H%S~�D$���_�0O��0�Ikdr��w�_���Ekr;�F����ouA*s*������h1g	,�49d:u����D6����'~��
��Q������VX��WZ�)M�����+3��.��6w<����w/�|v w�"��\�6)�S��^[K�'�Y��?x�����u:�������V����n�x�A�cuF01��
ua���X� �6�|��J��V6oCu�&s	�a?p����d/� =O������$�#el�Y1@]�����L��6��)_ �|q� ���0�����������$���%bz#�(dv� �Y�z.����
�+������|��������`3R����������0�	T�$��%)sJ�da���d8(�0>9am�����h�jg8�;�]�7!x�J�x��?.
��I���oEn�����_v��{�U@��z����A�|DgH��:�x]{��b��P������\��cd�8���[L�!���z���"�^�� R�5J�0���{.j/N���3�l��i����~���J�T;8�g����e�~����H��9O[b����y�U�Y��#��q
����������6���o�<������y
�B��>6�h����F����1
������<?�5��l��_�����7���������SZ7�*[ ��l�����x�}E]��t�O�>��������	����W���5y��a+��
������������N�G�{��c��7
�vZ;�7�����#�?"���c�5O�	���6��KG|z����^��/_�9W���<:���''�}���<�	q+�6}��Fp�����M���X?o���a��:���J�0��T;�=$jF�C�sH��S�y�G������+'�����h����#���y\��6��[��h�����7
\�7��S�x�Tg��n����������:m��Cj��-|m�^!���~��?���S�o��1C���N :8}#����o��:�Z?�mQ?���O�OO^����g����z��?��3(�#�n����"|9z{�?�:~k�����H�?��qv#��z?>k��>���Rz4��5q����#���o����i��^�����.xYo��_Q}yx�@X�<:��'����������������O�`/��u �/�O���7@�^�9�}��4`b���@t�i��~R�M
P|ut�f���������W��9�	�'���4�X/��1��}!L?��{xr��	��4�W�����������8<���+:���y�=;�&_N����?�Z6�?������:�J��N�'��x|��p��/�>���������a[��_o���2�Sg?���{�+������:�^���Q������:|9�8'M�>`B�#��G0w\ �������%~�<���??b3�?@�@��/�Dzr�����Om�9���iS���q��y��-~�ON����;�
?_b
����p������y���o������!N����	l��3�r ��g�	��{5�T������ �="q������s��p����8������YC~yK����x�?������j�mm+�&�������
:���y}�N#�o�
���3���s��|9<��8?����`�5�(
p����7z��X��t�o6�����A���2�"��.5���
_��O8����_��u8��+�_aV�\$�������U�M_��B��1~�������FK� ��#Cp��������o�O~�
{G*#�_����m���51|y�h$j|C�P��'���9b����Xg.�����OlF4��s8~������@h &6`R0�F��Ci`���_�Ms�5>�����d�
�7�l��kD�������'@�|�a3?B���p�`O�_��o�D����`����0f'zl�������7�h7������A��pj��N(�F5�]@�
%�%�*lLK<�V�*@M1��x��r�
�o��N�-�5�6�/t�����F��F���g�_���!������k�"y�DngV�7���4�D�F�d^W����Ez���e��w+q|��h1c������������v��	B����p��Oy���S����j�7g$��#z��AZ'��5�Kj��T�u��cm���cAP�/�_������|��$����q����L[aS��W�����O��o%e����b�+�S��/��A#`.�"��^A���5f�Ak�5T�1%�)]c�������������e��������c1��N��0��I�.���a�G���BeI�sJm��>XY�([{TR���"��%�"s�Y;u6��0�A;~*z����w��������f0D���
���*@�5�c�RY�5a8��������.,��m �����j6[?���z���;��/��a�.z�p�S�_��yx)��h����(�h�)�������5`��T�N�z�b�{tc���i�#� E&����h*eZ)N���C�r	��z���f�nKJ�D����3���d3-�4�����{���n�BrV�n�pgq�Fn%���X��4[L0�����.]������v��$�:�ew�E9����l��������e{���f�������\�������>\w�@�6i��3�����
��`�����q����n�[�rr�hFY������������<y���=���o��W����Mz��Jug�}�>����Q�7������p�MwEBH��o`"���I|�5�)G�0���A�Tt%�,�����]8��_\P��e����V���
��^�����7w�D8""QO������uE����y��8S)|]Y*�V�,���-�}��"�z���FAS0�d���
�
q��*�dM�#���'� �X��,zI��0�Y�H-0B����u���7��Mu[�'�71(��y��
�q.n-Byq3]8C��-�G��b���u��Y�f�Sr��r�����bm��J��Y�������?����:���o����?�����Hv2���3n��[��?	�����	�fA��p��	@\&7�S1"L?I��N���mu�~W���p)����p�������O��H����5�)YSK�KSV)�RJ�kS��)���)<_B�_��&'�����{���8�$[H����(�rV[��w	~$T���Z��~�Z�,��&���x��������Gk:��J�#���)��%RnvV�)�#�S��F=��Ed�;h]��7#�� 8�������w����9�
���3���p;��%A�kWW�\�>�O����Ea\&<<��j�Q#^wH��nE1ch���%_I<�J���������2���7C�@1]z�e���[v��a��g�(��n���l.|}gk����V���}j0�&�� V��s2����&���^�(n��&y~r����q���r���rM�a'���J2��f4�I�����A�?���+��a����<�K"Cr^o<cMO
OXY������2<��,=	pV&��>�;��}���#L��h�	X/y���f��E��7T�s5j����%:�3"~��c��4=�&��@�W��'Y�\���(7`1���g�i%&w��{%��<Nx�������1�3}x�����f����Rkw�>��I��H�=�8���
���x��-�����a����@�9�T����>�
t�����d�zY
��0-$���D�w��+����]���n��/���b�]{�r���������+�����p�x����Y+����]�����z��VT�.>�H�i)u(A��E������}��".N'kIl"�Jm��q��DPF���x�
���FV����)���4M���!���=�b�����F�������0���g
�y����*a:����'"�jC�X�zx��`�����G�������x�<�1+x��+�����"���$\�T���jo=�����[g�v����Z����v�S�i�����~��%��l���l9E��"������C�s3~%x���t.2:�k&r��^���JXp�p tO=�}�Y���*o�Xzf�������q,=�q��H������S�����7��4���A���u�G���E�z-�BS���C������t�t��f���b���*��|�ie7hV?�a���8���,���q�o��Q���>��6�Y���$���@#9<�D�3ip��@����j��/0�3{��,�k���$����I��iX�v���{H���\`����e�Q[���\���#�I 8�j;�W_���S�����i����'-��X(g�}�Y�����2z�A�,6^1�������Y����%� :h�'W�E�������C�5��XH91�����4������Y����{�i��7 �Q�<�����%�&4$f���	�CH�Bc{�Bc�aI�h�AW�e!)�f�3k���7l,,h+���dy�ZQ��V��d�6M
��A��<����t��k$���&��������TO���:��\{��M==�e!�wYV�/&�@D�Q/�8���<���������V	`����e~���^�v��ghV�1:�J/fr����7�C�J:O���x�����ep839w����6���!8��4�r4
}v$M���9\�:�<�gs�������3���1��R�o��;y�+?g��`a&�5���<��Gg��������z�������I[�:���9��<���1���3�&t���
���o��FJ���D��N�DeY��C@Va��k	�ch����y"���NN4�D��-7�~Z�l�����)=?��!���
���]�V���r�Ig��E%alO3s�t)�%�9�����>����,Uf�	�����)YOJ��D(����$X�y�_�6�	S�����7<��2:f�0�5;h������M]o9�V�@������K�[�)��4ON%��V�K������������|y�������������u������e��dF���8����=y��>�enfo'��x<��J�t����*���gb��N�*v�a�7�]�+�,�R8�Q}2g5l6e�wA���Ix6�����=�R��8��2���"��o����zM�T��`�5�����n]��9�X�a����
 �iQ)�����_oB�yU��4j���X���=@rO�O��cN���k��;Vs)��,�4�������b�X'�$�����:R�%�P��$��Q\���������yw�d���Tv�&�A�}3�R�B���m�M�
�iz�z9u�m�%�%���%Gz��t��O��:�<L��`hR���9����^�,�������:'����p���T=S4�o�d8�������54�s:��/�A���w7����������xO���:<<�y��{3@�������A�e_�P����&��z@���e#��W6��[<����Q����M�G�~ �cXt	+�������*�ns�Z��]8�-#=}|*V��I��+Fm�S�z�Bo�?�)���0�7rS
I%�|�A����Z��njB�kt?zs��.���G���(����vM~��\��[���Z7
���s�.���w��V�8-�����,�8}�R};<P=�)t85������>��U���m�����e�&����DOT�&�]��b���*x��_+�����
�)P_)8}��� �t�^����GC���r������a��0lE��"�o�:FQ]��:|���a\���+<�]����g��U��zl&���!�rH�G�����`?a/���H."��������OjtN0����z�*��"���RR��o�'U�0P��������'���(��V)�a=5(��vw7�J�}S���r`(��d�U�f"+�'2�������>Z�63�M-\He&i_�����r�]�X_����o&5E�_���4��)7�9��t��I(ET�PF�(��1�P������G\��������$��du���@��}�]�����2��r�A��f�Sq���z?�C� ��n���_,t��]�L�rH<@��(��W�sb���$\B�������^.ot�.�/:9�_�1c�e)�I���.%N��
'S`W)���3�Y��4C�%7��������,;�ZQaM'���5+	%��c}+����6�k��MV/n��iw���/;�������x�M��_�&�0���?7~���~��t��*��U��6�x(q��~���������p�Sm@1(0���Q)Uh��WL��by<��S����8�$h��j-��Xd�mn����4��z	���M�3��'!)��S����\�O�1�v��J����/�=KS��9�f
������vv'Z�2$�G,��rVcF����I#�9���nO�p�6f�d�dn^�5e)(~{'Pu�����9���dl�-��E����qM����tSa%%O��U��L�uKd��G�������	�S�2��]Sr��u�rjH�x7[�y8t��%ukx��n���x�(n��Mo�����v��6s����������N���g��gC�n��csOrFO�H$'��k�gue��7�p��P���4�q�2d%O?�rdud����
u%l���gE]��T�Z\��,��DN�i����A��a������"�d��6�+���.@���n��pl����!�����`����<���$(���L�)��.Rv<���c��$���M�9�����D��u��5�{R��X��7	U��)�%�=��g��2?�����.���e"���������B�!o��P�&�^��0��k��N�W���Y���u�
��[�����_����[�t-����`����1N@�+��:g/��
'�Lg��d�E�D���_g�:��Uq.���;~m�.��
h����q!�*HL���1#��`���8��z��i��"�8��(���	\�W�����Z_*��R~`?	4�����x�\�$��>���!3�
B|�$)�����}?�n����n�`u�<9���!��d^�-<	��c��zB�K�By|�:{���4�f�(RPk��Su����(����n�?����[��;��0k�\��DF[���Bm��D�����L7�h�6��������1�~l���4���U�i��J�rXA�r�C�`�I)�u)������@a��!xS�|��d��i������At��CC����S8�>t'q
��O���������p&���V�h���)��������X����S�]�A��<��	l���rBK���-��C����
��$�qJa8e(����xd-,�{d���c���s���	,�e<n�S.��q#���k����������C��tDz����v�F����|v�(qM�?��^��#���U�Q2���aK����.����5w��s�����|rP@�����m[�imh�;E�E�A����� V�t$hjx���X����rn^�)m�it�+��Sc����T��@kJs�,���vh�.�Y����F�U�_���*���+�q���z������zMaY�&j�*�X�������}����!c����[�\��.|P3��1����[�
��T����>���w������_������K�bA�@&z���s���_9����+�T��I6	.2���:���C�#0�I����nyQ��%�1L�C�CT7B�����@��LL=�;<�\���`x��M����R�k�U��#KoL���'2K����������j��F�������m�y�0����'�4��|F)�R[��Qn(��Q�Z�����xuz���V6u=\�6����l��+��Sm$����C[}�������{�'0q�=y����J��$��2	,�S�N<�G�j���B|�'"����4�1w��D��e����o��h_�Qs|n#�W��P$�?����w/������pP�z	^>�@bP�nr�f�I�(���(����6��3�fM��J=���-�����VB(�2���3Q�YA��,�3�0gZl1��+���fE[c���h/I�M��`PF_��F�v��P������\,D�43i�lB�!��H=$�L�v�L��U��=i{9�%�j��h#��<��)/@���KR����A�F�  +,��o�%��K|����}�&���x�j�2�<5�_�a=l@Z������f�RUj�*
��@����`>�e�{�H+��Te[�+��}�0GV	�dF�s��6���Ug�\"u^+��r����j�=�5i��.��M��Sw����kf��ie`�:n��X��}�ST�<2��E�����H����n��J�6��lN�����:�lFg/����,um�]�1$�	;�#����b(�6qI��M�\f��g��"T�/�4���R%C�������GK�`���O����o��-L�&s�r1#j1�Y���-��V�/dqH�!����L%��^�z0tt�o�6Q��gL���B���&���ly&����!=��a�H`y�r���csz���a]���?U�\t�^w��"�u�N�N�;��|�v~13�&	+�����FZ��M�_���a�@��e������ ��\���5�	� ���
�V3A���<Wj0����b��KZ�&EtT,r�H	Y�bC���64�.<�/%��]0;��]2���"�FI�����>Yg��|1T��Q���TFj�9�6�;I�Lpn�Y?`�-��Uz4`x������o����'"S"�$��Y����(��a
8��)D,V�����/h�C�Mw�c�Rf')�${�	�+nR����������s]jY[]�����Jp�,�JT�vJG��f�%khQ������>z������Ua�`������&4f����BF#��P9�����������b6L����@���q_�d�z,����X���Z��-�Y�V�QCV=����H�}�A�"���/�c��.����8o��l=��I�'
[����q���v6���q�<7�jIUpk:,���I�w�D�J�����oN���TE;�i��pY
�J3�"��E
�g����j��%��l��,��L}H�O�<�`���-�����)(�n>j����U����?�0��$ ���I;�l�8v�
'K���������wD@p���/�Q�_;�S��M�����0��!���dQ�I
�$�^��J�V A�t��YVz� ���/M���������������#Ll\�����:��
&%@��Q�B���gz�_?s�|+��E,�L@�e�?�t��b^$����`�L���;����o���y��'&�X�Zx��#�I����+�a4Sr���$��]l�Je�D���������5��6B=aG���r��b1D^�
3�&�Z}P�P����y*��L�WP�w��&�R:h2�Q�>:V(���1�L
N���{�Z�=Cn:����M	�PD���S�)���S���t0�^��8�����)����7p�����G"����r��#'w#rC[��X
i��
4�QCIt�.�� �� ��76���x<5�A��F���TE��@��=���/=��~��([���&h�
.a��^������'zH������)��)�����`��Mk�d�G���Ds�o�xsxt 	��M�^����_q|Wk�#�y���N����K�������;/
�n�b�SX;��)����9^1[|�e�[^�*C���1/�J�*+O�D�+}R?�E=��
gW���Nl�l����u)��s�h�mL�{��������-�w���%:D�
Qh��0�����m��������
3����
���Y���8�����\��������I
����P��;%�[*LwV��,�<��vy�������B�f��W�p<i�A��[Uo�l��bf���a���%9�������Vo�,��J+��l�������-F(�F����X���P�5��q7VFu��K��mz"1]n�O�.E�w�L3z�L��=�������dK�;�"��40d�P�_�/��r�hp�G���L�n��2��{��0B��K��`q9�X�����X7�u&vX�� ��;7�����K��*)�j;��B1�F +#= 7�fi��z2�s�����e��HB
	\���bl��UP5��k]>��U/eGE��O��,p"������{e���) ��@"-,vbI��Aj}
�#'��|����������'7����b��������}%��;E�9VI�iLH�����Oe����N~��+%k��)l��������x,�u����^N~�������D&�,M��)�?�/�Z�������O�F�#'�|�����G������������}������UO�MD�����i+��jnM�,OR�C�0����.���d(E����<���|��vp��Y�-����PB�
qe<���������Y�{��eq	�n��L�h�0"�|�*��������R)�q�a�W��;��L���^���V���}l_���
?���?�S�^,���5a^*����C[j6��X��$!|���sH�1�R��?t��c.�����`F<X����j9 ���z"`�5�
K=������0(W��E0����n��};���F�S��Ey��zZn}�����������@��D��S.�=b],��+��_�B��:���m����6����|>I 9��&>O[t�p�F�`KvX"�+C���s�r�X
^�|���^�#�K���S��p_C0]*��1��R���/C��z���J}vuu��i�����X�r��m���P���Q��V����\S�c�e���������[a���I�c2W;�r���U"A|�w��q7�t�i�1,�V�������Tz�{����]G?��S��qvt�����Z���w����G�yz�������3��*����g�S�e	�>�*|h�r}�����v��t4�W�=�T�0h1����c�`C4Yx���(|�7�2X��v����Bv�t�*>���c��lw�����i����oT��2�����fl ��RN��p��zM�����~%��m���&^It�H�dF�2?\�H@�W{-�J��r'=�^ ��":gpx�29S����������`�����gu��t���Q��\��x�]�4N�*eM�x���aD��F�����������W��<��;']��f����_�K������Qk�Vd��	�"��`��wN8gH���F�_�n�f��>=E)��>I+�[`�YQ?�~q�n�"�0f�"mFH,�.�KH$qa�����H��gtW���~�J��>�L�v>�w��~'����N`D��+�K��;�_w-�Y�`y�=�{�������Me������S���7av������E�a#��l?��!�D�~����8�=����M��>��p���YCU��z��w
��X�?��W�������^e�[�Ng�,���������g�0R?�����@@A��(h���!��X"�2�=:C�I��;8a�����X�3�c���'�����qt'-xH9�_�A/�_���s�8zL>=�3���"���7>V���a}nBG�$R�����Q���I\��'$���p-�d��	�������������f�!db����|���pN\	�,��'#���7��B�
@Mn"���hq��z�����[����
g�M�kn;���[� �����M�5���'#�a�W����E�F�����ZJp[��E��7k�e:q�
�FF���Z�[��l#M����z�^�P�
���#M�h��~^DO�aC�+�
�������q���.
�e�����Y[:���*�c���1}]��<��O(4���^Z�������du���@?����r��z��0s0q���X��V�z���+WQ�Hy�RCp������$�sII��RR1%����>��9���w\Sm��m
��)h�<��{#,g������L������<\�PT���X�7�1�"��H(�y6�^�Y�EI/����/�K)d		XK=�_(G=~����q��	�Q�
Vx:�z��S��H=�|��pXzV{H{�/�*M�E���;lkd�:��5&����A���#XH�zQ]����<�Y������.�nv`����* �/�7c����������\0(/�r����;����_>M��GU�S��-����aB��zs��L�����/�r�1R����)�h��\�B����`J�����������#R7;}��~�Xg�����~��Q4�Fg!%k%���F�CW�Vz�	�sZ�^�N�"(�eJ;�<��2%�<�]�3�@�0q�c���Uh8���#��ewZy�XB�#\P&X.��g�V��j������3(cx����&C��1��������
�m.�k�-��t����#fv��i��L$`�
���qv��Hz�W�-�l�!������pJ���qJ`�F#{��Ku<�&��SI�@��a7>nqk�\���UE�J�Y����9�5_'�r!�W����U�Q����0�u��T����13��Ub)�����r����ax�E�]��b1�.��K��Q�H,�]��PLLU�Xr�5%��t�k%q�JZ���,s����Nj�v���l��?����R3+.z������,����B����{�<=�g������^��@�}�U��d>x���t�-�W����B�8��E�����-A��b
����X>	�Y*�M��)7��z��F�H�?�����C�j�XT�k�1���E���O!{���g$q�bvoT���C�H���L������.(����h8�Ag&�K��c���T��Aj����@F�Z����n$WO���*���"��]�SI���pu����:���!���w�?uT�����9�7���D~?�h�!N��p���h����
z����!aFb+��y}����U�$%�FI�O������i��YO/rpz\;<1�c�L�B�h^�&�������c�9�CS��J4����px�Gb���QH��q!)��gd;&�)�~T4P2���;��M�l��@Z+�����.[���c�q�LLg���\��capK�W6��f���&X���V��y:Ox�Xf��)����<�xVI/
����'���B[y8�����&]�I����|��U���v�Me|����n��bc����i�O�4p3e[�e{�
c�N� F{��+��D����Az)��tNv�%�s���&��5@��t&�hx���M�	UC�xh7(M����V��~��6�3r2�q@R���ZQ9�3��M*�����i
��l���+S���<
grS�����V�G��^�J4�%��e���Q���	��R���"n$��d �r��"
�+��Q��L��L=�rh*�T��<@m8r����b&��a�=�o����Gj��1^mL_�B�d�������d	�r�P�0n
4���h�]�W�����0|_5e!r��wMg������|l�P��K�0����)K��f�a�#"3���M��:����
�!��9���i�$:����4�[�e:�+L����
r�h�KGJ|�I���x��\z�N�����b��3���i�7�x�m�d|iEQYG�b�V�C��y��
M�x�B���*4��h��e����N^���U�&c_ZKu������F���gmP��:!����v!QF�VV�LY���:)D�4����;��{��Y���t3��U>�3�4j���M�Z%j��-0������u��A7K�#�28K�`�A��z�@JV��jY9��J��%���_����e����U��/�}��D�z�'����D�d������s' �X�	-��a}�F��L���B�c�ik����"�g���`��0��9�g�Kf��G��0���v��Ku�!�4Y��N��R�JW���V'���E�~:�������mq1�����k����N\.�_�_D����������T*������J����O��nu��%V�s}C������q������ �Ip�	�j���%B��m���5�]!��)>_XV��?��S������luOc]�e�)�e�;��u�}��R%�����^������&Lv�:�C�����1��A����"O�
�|��ibD��`��({|u�����t�3�Pp��%�'��1���4��O�"��yx3I?��F��/W#6��[�?v'�IJ3���/���~�s��3��Xo���Z���S.W.�/w��6�x���]�(n�������Gw����6^�����e����b��l�=*=�����79��.,�����Y��;2a��"�}�������G��IwRfBT�&:T�*�"��em��B����
4v�� o���p���c�I;����0:�"M?6_�J�o���������5 �����+V��7M�;<Yk{/a���1��4wv�;Hn�����S������vt�|�����I��j{���������_fj����Bf�0;�a0�:�I�����J~����Dw�d"o@��
�>��s
-I��|��o����B�%�orS�������F��j^v��V�
y4�?��n/�w����
����et���da��_E-C�;@�[+����
��*�n��u�I�~�8Or���I��T9��j��]��[��h��N�MdM^���M�
�����7�t�W��Ou���x"�(w��;��$������
��>f�^��W��!+\���p4��C�5�9���	~t����v�-��G��?��)����t��Nf��B}����Y����8_j�����5�-�q����K��
��/���N����z�i��'�7a��m��?�m����d�E,�>���!kI�����#���������a�a8���pr��2(�$F����8%���et�B����Ox-C������������#
���>�G����� ����<��_��9J�j�[�<��������!0^/�j�b�R�|</��?s(��R�F��S���Sw��N��u��X�?�����"��#'��s�x�X�B��J�t�x^�����)�1]�����REbx<H��A��!0���{q���`�"TO��rKe����]�\_~�B?�*C�)��K�O�q_�.��*#}�!P?��)�y��j_���N��S�
!P'������p��4��������*��rysg�Z���s��NYw��Z�R+���L0;��./����G'��D���fm�X~�&�$��h
�����.�����/����^N�6�g�QM(S;hR�F���B�L����
���?�
��E�:��L�X�%������Z�.�����x�+��@����tL��&WK��"�L�X)1�������&��gJk�,��������'i�����g�������$��m��A�F���P?^Q�W	
6��A�X���0#@S�w���W:�a#�,����b�@3��G�aH���:A��B�!
�����c8�����CMU�Q	����������0)�)���mu�v��$3�-�4z�Pu�������M
&�
4Y�te�bx3�D �
b��c�,�*c<b`�>���*~ ��6��g��
;���A��7G��Qg�����z�U?;���
UKK�~$l�%b�C���6�Z����l��N^�I�+i�>�#�K�IY�����{�����f.y����6�PA��
����v"& ���
B�B<x����C��AG�� kT.���a���%��|���7Zg�s��=F��mTlA���\xA2����?|j�D��{������4�+'~���#Y�G�����.O�en��Bo���O�E�Ve�X�n����	8����v�e��V���+AHI��n�i��|�o���x�h~�1��v+u�� �w���������&t�D���u����p��^w0- �0a/���*U�*����!���td?�/�t�Z�(V6�7@�Y��a���)c*���������F�	����?����
B���� y�����j�4A��+z�����k��:�%�J�������(�f
O�R���R�n�'<���K����z�sgN�cH�4�S��1�v�� �m���]����E>J���*�?�B,����O�O���.��b	�����	7&x�@��C�xec�j����)��u��D�x��]E���.��*�tR�0��F��w1�_�<������2������;����E����om�8��/���i�������
�"@��+@���znm`vw�,���&k�o�#�1,�;N=8"�.�!��:4]����������U;���z����a�N��%��2�V�B�/~TH���;a���8e���i��SP�
����Z�o.@H��v���"*
���\�2����G��?������%��^t%
p8�`��Qg	��R.vN�Nv%�����T�B-#�;2��bI(!��6$������N2��fuc�������h������vm`Oy<�E[�������^Pbp����h8��0^)�������h*>D��h2D�[�?�ES���Y=�Eo�;
���=������K�	#��z����E����_�X���� ���-������0�����	�,���6E�����@O
(u�V�����qD��8�������2���1�d(>@�����	��w^��d��@�p���9�a�hG��A�n;�Ta�-��:��.oz�0��3@(�ah0�2�%�NQ�-��\�G��Nd(�~��(�����5��pB��k=G
��]mN�(���r��CS��Kk�2I��/,PN�n���:f	}}{�qg?-D�*�\6�g
�FG:(�����L���F��
�+����=!�9�3'x���w�n��#�Q?i�p�(�Y3�]v���'��G|d���W<�Y�f���E�k/X��WTr����q��#���2j��(RG./h}0TR!����E���Wr��ac�9�h6�*�y�,4��o��^�2��'%��]�n�6�Fqc�'(Q%�C��gITA�HZ�b
�J���	k�Z���!��U1��mW��c��S������A�ZJ~�6�����E���]7i�]���XL��3v-���K���������7�^�m5N�j��
���<=����C�v{�R+�[���]v-�d�o����x�P��!�������w��T��I�%����g�p��x�����	�Q3��
��6��b���{J�5���;pO��'k������C2m�y�|�,C^��
�aa��Ca|";��"a���J��
cBS*�;�>1;�0��G�5�>r�UH
���J�b��\^�X��v�r	�v3��])�yw��f��f[��2��*��Q���s%X�T��h�_| ��
�</@h�$[=� r���\�X��Z��Ry��y�*.�A�RE���!H�Ao��*_T~��vYr��w8���A��f�����{-I����d�������n�r�ejW}RS#�E����Lh�+)��������.�~^�������E��Y��xxY05���)�qsw�X��p��a���[�mQ}5�p�������Z5_���
�u�|�RM�����f}�^��'7����3,��uu���W�������B�9m������c��A\^V�����n�n�������G������Z
q{���������(�o��:����������i�g���P�����<?=n�������urzR�\�*X�*k���+������~u�1�k'�q?-����k��E/a[���b��x3O��]�:cf\e�������]e#W�M��f�*[v��<U�9-+n���Uh�����5o7�[��u����:f��_g��}�K�v*w�����y��*Y;��ggt������
����3��s� p�� ��� ��� ����y@N��tz��q�v��yw���|;cg�Tn+���T���(j��_�Fy���s�q����%�
G�����K�Xj�A����>�����\��Nz]�!��d���v�����6�q�V��>k���������������M�4��O������ogAF�q���V����
$<�UA�&�w�'x�;Y�7��~W��m��2w3f�d������c,N�C�!~�LL�T;���u{{��Czn�nU�q����
E���g�a[��,��7�1�[�&���!I�������+!1�b�J���-�@��-^����������������>�7lRz�A^����}�:�����c��N����si-�Z?���j--������������2e�:l�
���R����7zY�+p�W���%�����{�b�#�EB�!/G�A2Wt',�S�\�f�9��N��UbC���Q�����Y���usF�FQ ����!���)n]_?��X�wP��U�y��g���
y"�/� .Z��2�*{�Y����H�G���m�
�`�==��-(�Kw��T �&��G��A���Gm���������V��&��������_d�.-�r[x��`/��
:�)���a���`4<5O
e�.��0�s�7M�V�g4'�a��M�m�(T�C�i
Zr������=�3:�|�=����=gOy!� 6���h����	�(_�Yf���~�Q:��Rq��$09���Q&]C��}�)~�2y$N?b��}��J�X���2~����U2���StN�2����y��?��Y9�J<��n��jnC?�����U��/�T�v���zo���x��wH�y>��-j�G1�F����8yr�F�bE��m��jeko'�T���bU�T�@;����#��	$/T��|a"�qu��%�;	���@������l:���V8em>��e�5�}��
(��	��	�s�Ok�^'��/���
@���'��8z��(H0��@�+�����{m�>Z�7}\S@�������,���O�=;(=���RK�o�)F��){��Z������vh������m��a��;�h@�K�3�
�}^tj^��x0�+���G�j�YS��";l��q��[Y��kr�R-��u�[ �b����m�n����5����9�|�.�|��mI�������cw�X�A���]�n����['Hdb�|c��tr��
������g(�a?C�c��0"��x�����������,wd��&2���5%�Q��{�l��:dV@�$H��n�#�Gk�l�
pJ����[�����O�n��H��:E�G��[���T��1���EJ����x(d0��!�:�K�����8�h��$tt��C��W�@�	#����Y�(
�[�V������$'C�����!AbI9����������B������|f,�
�V�U�`D�P1N�#�+���(��Ci9>\z`bU�$)�
�[�b�M�Dt�)����
��4�7\-�k�2�M{8�������[���1�����d���;��5@���vqs�E������0{�d*.��R��o����&���!�wM�pD^C�11d�0�r�K��I}IX?�����7M���_:z�pJ�s��Y#\����)�A��`��C�;%�����1��>t;�k���:��������c�2����S�;+���������C��2X����B���xA��^�V	{%|�3�J�(�J�J�]�8H�k��$�+�v.��������N���00lC���;�931_x�)���P�����<�/���V�E���,��E�k6�������AIX�=�O�	;77����7�8�������A�6�we���B#-�Yp�bw��s#�L��9�=�4��=u�y ��S^�ux����������s�U�q�]�$��:�0��������1 @K^���.�}����QOz���s��>�K��9wC��s78�dsr�Fx%�&f[��]���8K�P�O!�" ��P�t�
:��.[7]I��}������H�����
�+����q��g�1�-�����#�����m9� ����z�f�B�����S���Rk�(���	��F^��8,�Ge�nlmJ�����]�!M� ��	��IQD��^�~�����������������+�����TPP�7�j��������nH����0��L�����Ia����P
��I���+��(�k���A����k�S�d�Nx�.%E�k3��L��F!�%�b�*"�NU"�CT���0N��3�k!Xx<��G�R����������3gx�����s�h�������j�� ?�b�RoR�F�~�G�u����Lm`��_r���g�Ut�~*o�'7c6��\'T���K�r�����+�(�F��������s�8���.Lp���p�L�C�W��z��h<�4�^�����B���FN/���o���/��[z��z��������I�Y�����Pmdhp�0^k|�r��qC� ma��%�"��p����M)9p]X:��S��9R�����
��/+�^k���~�W��+�\]��B�[=T��6stQ
u����S�I
�v��2������m$[���kl3���Dc���	��7:\d�f�2�I���������io�������9kz������L���v�&��H6I�6;d_"x���kk��5�����-=f��&=���:�L��W�+ub8a8�B$���5��ed��v�UNO.
�w���w�E�(��a��	;P=���L$��g3k87�Mc��n�Z�sw �a�1�Ma<+��<vm�{��m�	$5�q#���
�W�-,�pA*�����>�#�P�<k��'����p��9
x��
����s��7u�s.�-���D������H"-��lx�[��� ��:`��� M�uG�����#��K��i�TK2�
���ia3�� w�.]]��$�����N4i'��gH*��>��c��Zr�j%��T1u������!��N�"��vh�Bo���U���C������C�C�����wZE���d�O��Jc����1���?��x��~��0�vt�zs$���u�lJ*���K�G��d����cul���eLv���A�����o����O�&����El������=�t��C�R���=��U��y�X����i]�fKZ�������_p��j�_?�T��Uq��<��k�E:�f��Ar�y5~8<c�tBX ��YW7�^�����3���wy����bcFv|���F�c����3T=�7��}9�ukN��3�v
l"}�<��C�hYT7��\+�'����5�{:��5U`M�@]����.�X�nl����a�X���"�Y��	��zR�v��Mm./ay/$J�{T��E�K�Q�G�����:<sI�y��F����x#��Gp��d�=����-��+(�w��������*�+��JU(�T�x�x�1
	�����J�r���)���U�?����o�����sEl|Y�5�����f�L��y�~��{�	+
":���n1y(K���q`��u���	e�@������#��f,G���]�$h1[�A���@����?��@:����[R���&f�a�s����������W�\<���)��m�h1��~Dn�]�j�2{m�����Ln|�Dj�"#��Y������T����K%�$���&1N��"&�=���}��!k�WM.�KT:(�Du
FI��L�n��?dj����h�'d�������-�u.�_@f�h�G�K��K���xsH|��J�Vb�ku��������hQ�OO���}<L��g}~�o1���uy��$OO�j����c��:���X���:�`���V#m<�b��s9���}9���\��b��u+0��]���Z���Z��4W}P{�!�At�=���|��9������,����6�$F�c���Xb�(���������8����������}J��������������c=����O����M��	�/N#gy�yT��(<���xF�����q��T�X�z��4����h`��[�z5[�\Y���s����x�"��T�����Vy�v�?������fb��s��.����_R#Y�e�������{_�a&t���z|9�u6�EJ�/����T���{�d:�����1�;`���*��vvb^��+�@������?e���PF�bc��m���$���{���,(?�gb2iG��VD��o05�c�R��A7���U����6
��|+���/E|�{���Af�g�m`��Est!S�{�k�I��q(��G��a	N�����0�Z�-��P����[1����N0���zHC��V�S�����S���`c��� T-�#hC�g=���(sln��<^���C�{j<f�M���4���>���9����$`��qV|P]n)��{�0������>��7��rg��'5R)�����:�����GA��x})D���m�v.Jw�.$��b�p�w-`�p��NwR�s�������r����X9<9B���-G�m>��K3����os
��/3�����������52��l����qn���c�7�a`��� 3�WuZ����	kiq�����>B�u�h������d����Jb��z�
G[(���.�����D"�U�+j����]�ZP2�[����N�%�
Of����]�;���������i�����qk�>_	*���%���������R���
3��CY%w���?����bkR�4s�b�7��V�Z0 ��g�/�(�Q���;V�:�
��weE^���t����X@��i������Q5��hg.�f�.\�,p{�[���=/�
Y�������L�<%���$ZI4�?@7r�A���d�k��0;���-�~�s�������]G=�AZ7F�?��D&77�{�y��{���K8��}y�8'��X���\��%�<�>9�uVC���<!&o�t�'�����h&�J��
��>c��Y?������z~3�5�}��k�I'�� Q)Q'Q���a�Q�A������y���e�zY�Y��a�T�P�L��_�/��>��h��W�����OJ���>+Aud�]�W<�{q�_lcS
�Jn:�����5Jy���������Xvk.?��P���U<�
^v"Nv���E�N��Y+n��\]�����^�^�9�s�,!�d�h��|�i�\�� FB���Q�� x�	��/#��\:�76�bg�'�g'���2�c/15&��k��j)���QH��`�1�����$��i�����!��0u��"Yi0!X�	��~3�a���)�����!�g���O��N�h���[�I���K������%��0T��uP'�K�TP5P�c�b����C�D_��z���YRK��eac�c�g(�)�5u�D�T� �u$�ef��^������zY���jep����$�O��U<�0�_�����9}��4
�dR��QEf~_L��Z4�,.����
M�^^b�d�-�y��E�0\n�}N.wF�R�`D���-�,!��w0���9f�gBj�����v�$D�F�i�����pR��f��Ig���/��-�|b��~t�k���U+-��wQQ<��K����Fi���3p$W�A�N��%�A���G�h~!�B�Bs��.Y�&���X�-T���l�^���,��qP�Sb����Y��V���S\_+khq#!�Y��������������z
�c���1et��~�X���I�(IB;�����)m��=8:��#F����i\ �O�'b2)�(��c���*����2�������5
�_�
Z��[In��:�0k0�3��A���Q�����4t�����*�c��z6%�l+eI�������EB���?3�f&~�J�
$��q�'k�
������?�R�Q3�%�`B�F5������m3IT�C�u(@�]�#��ZxG�a���N�8��eIZ/�YpH�*�"
�P�?<����u�A	��0FX��!�_6Z�|����vR���T$���;���8(
0�����
����%���|
����K���P����[���vqv�h�:�7Z��S��p��'VZ^by��)��`xY������V
����MiI[�����"�J\|Oi
�DZd����Fq}O���b����������=����+�7s�9��|�������(�P6[�K��,����l�8tgz���2C8��on&�Z�d�J=��C����m~�������c��`.`��q#���I��xxY�E�NN��Yx J"�
�g5L���4�Ly�A��\@����%7����K����a���%%��	�%�	=M�w=�K��kT:K����2tb#�����'�9Ym�s�l�������;,���+�*�hg	��w�1I�2���}Od���D���}*���M�'p��
�Z{z5#j���������'E��K�dG	"��a�s;�6P�d	N�?c�>����"M�4�	��5f��UO��,�����p��lFn'
�{��'���&��EjPv�H�����!��K!��b���V?+{�TL�ai�����t��Xm��[��Z��5H��m�7;��l�oP���N��������I�S�
�?�	b%"R�Yj��
l�yll�K�����o��WI]��<���z���I��Q����?��������]�':�&$|
+hy��`(=�_����u��\P*Z	����ADN�$	-�4�}z�LkJ�����hn�@�8��c�Htw���������,�gnw��a�;��� �x�		&���/l[C��\I�r@�,�$,,A�����{�v:��:�Cl�]DN�c�,N���9�7�HN��[OY������8���aF����56Y��x���N��bG#z%����-s
��&���h1YQ�=w�MP�����KL0�S$��r�Pxi���%�u����5*���?�<v<<����E��2�&
+N�8��81_��Yu�q��G�qO�K�<��+hV�Vv1`\��H��|�F��o'�,��*S]v&
���%��d��;O����E7�W���f��0C��e�����_l�������P�L M\&������u���^���]I�Vr���8���yP�h0sa��l��z;�]�����.}	��q����N����O&����/z��G�<����%��\?t�<U�4_�r3_Q�n+�O�ZG��8.�`����!��pD2�����j�>����n�!X���t�<n��Kbgy�9���1���Ar5z������o^���/�
�f|e|c�
k�9���"��]�A����8�OjBv�oE�d?z.��9���x�7�G��bB������,��D�/��?��t��T��U��+���9/�����9mr�Te��nX���}��==���0L_��Q�j2I}69�	��>	_T ����m�������b�A�����:F?��e���~E��h���
H���|��	�<�������3�*R������������s@��q�S�����`w����*=�|0%�����N��={��L��Eo&J�J��@��4T����+�z�E�\X(|���+�I/L^���P,27��^����4$z�zJ��L�����	4���Z���V�l$�p�2�)��6�Q��8�X4�Z/�G����/�N1%�����]�����$Z�����p����7?�2��3�{�Y`�KxT60���feM�d�m�t@|?OXO�?��'V�?��� �u�	���
q-��o�4fkKX�_@�7�"|q46�3��%�<Z���\T�D$Q��]�=���i��B�kc��xo�����+'&�Pu�+�������s�m����a��^�Y����'V5��=�
m�p+I>:#��j��6�H{���M8)��w����T<)=)j�o}��l���=����;�
��%S�l���mG����VL���p�M��.Y@�z)J�+��hu2n�^D�w����L���j����6�8�������x���]-�7v���Z�i�����T*�h������>��u�q�����9X��h�����p2�	�|��>���d�zM��]���f�����p	����lG��7�ZE�8f|��d����b�8|�i���M��6>r�:��9*;�A������qzB��N�����.��')�|�C�&4������?Z	��i�V@���~0����aSc�������c��cS�"?�����<r<�����'�=�'6>B�giE����CC�db*��&XX���7�t��������B�9�����-�-Xe���YV����S���q�8��4����k/QK��Z0!������������(L�KE��0��rxQO��!����Jm�}����G�e�B�I��v���S��Hu�jWW�)q(hY��2L5�A���l�z��)�FN�,��0�n-�I����p�����&>uj�,�'$�J�����cj$d�w��Q�Bk���X�(��[��j��d��qPcx�^�v�[�<[��*�$�6�9��b�����Y{��\�jO-�]~�M��&zG���E�
@BA�%�a�E1	����f[d���u}����C5�)w"	�WA����v�8L������>�a#��H&��bdl��l���E=GK���~-��1�o^D=[1���M��MfFM��	�$����QK�����S�����L���� ��C��
)}Hep�a�?�=�������e9��"�t�ma�����*E��b��/�7���r��'��*H�yX�A"QH�Z�3\mg�����K�h_��i�id@�X�>����p����H��}�B�3}����SR�4���U���������Pg�
�HkGx#�=���*��D�F��gx��U�i�������i�(�����������a����xJ��YbEo8|������~)�eB*�>*?ZI^�b�?Zq����m��_DS��f!'�j��P?i5���'�l*xm��6�o��Q�zJ)=#�A�L��g&�l�x&�����V�d?�	��D�nt�AG�y�Z����������������E~���
���g���J��������G����4������N��@�|93|PHlB�i4�vC�I�d!A���}���[@&�p�v�1s!.<aD���b��������N���
����:��y��6%�z���p
SBWK|�i����L�9��f�B#{{�����3�U7�t�v���
����1z�\2U�X�m@eC���C�=u��9C��������${TROB��w+*�n�
�+�o��*���/�g3�����������,N1W��.��0��������D�d��)&.��p���H*.A����,�����
�E&�{����K)-EW�"�5���%B���GvZBI�Xot���]���"�T�I�A��X&��BN��<@�Z_��������rAy*�`	�����;F{���e9���SX���J��c�LJW&KC?KL��g(yk~���"M��4gg����o[�����������
�}f���%�3����w�Wb���)��:�g(��5��%Mp�Y���-&sbLVpD,gR�&b�q�i1�Ff8"�����������(�lzOU�7R�%��f[R�FI+��`��{�����}�������S��w�"����U�l<��e!������IO:��F��h�ET���������:"	|�������������zE��������4���SE��.3%v�0���j�=�\��]�~�~M�J��*	��4�7b����hv�n�'�lT$��uV��bkN�$I�H�I���0� �=���2mm������������a|G�����b�?s7��#�&	�1����b�"�)�q{8���|������e���s$ �{8�PB�DF)��dJ�@�S�q���}�����qx�S=�_;)�������\;o�����g�PV��*����]���I�F8�s	��E����l����C5��1��M����@�u�^�s5�(���������+���c���QX�"KP4����D�����]�0��Dt��Qd�%7����]B�^�U�c���*�+	����*	yB%8���|�1{�T%�J&Q����^"S�;}�}}��:���%	��������wob��a�;!%	x�����6C�P,\����/��z�w�VZ������!z#�p���J@���JpU�,&;t�mnV���=�5����|%4!_�#�:z9x4n+��O�e6 �R�������:�Zd+ju`C^����W��;�a��=Z^�$���'�7f�����Wp09!�-��s��Tran�;�����8Nc���m��:8��&)��f7e<�~4@�J��`�NX�	�D��}����}�K���e9�L�4�zw�t\�{q4VW�-�1�\�s�'����'OK���<y68�[>�;����8�*�\?bFB���8x�O��kZBj��C�=g0��I�t��>M��t.���$1I�l!C�)�OT����/��C����R�8yR*J2���g6��kw�JJ��$�be�Z����D�	��������?��"����y�44�me���ol�������?wK~�$J;������	:�)�"9!:��r?�K������#pmU	\��dX�$��;r*����lmo%��`���X��
�}>>��><��" `S��{@V�{�JIv��*�L����(+�uX
\�DeJ�{��'_h����u��sq�<���Z�J���<E ���+�z�j$�	�Ej�����}�����<���3�C�a�(q���:������N��e���S�b#��&�5�$?N�%��fC���9U�&hPV�!�NK�����j"���N*�M��[�o�����G�@��'9�(�<S���P}����b����XBc-g���L�j���4��,�i����D	�
F��ZCk�R��7�����5�j���s�>k�\��:-���L�T"� o"�YP��]�]�SuwM�[���N=�`&������gDi(�K�I�l�})A�V����%[�#`��
������<����8������n�m�Il��?~�h��F���U�ntN�b�����L�y�&Q��bFwj���l���d3`Vp�����	J�����y�Q?i�(�Q�6��g�&��
	/��P��`���]8��B�������Igg�Y�mx3�1���/d���]�\�	�< ������gX*��l�p�7��-��}��f������'0V(ayiS��������9�xF��'����g
VC��L6`�ig2��V���-�������]���vq}@��-����q X������5\%��-����L`V���&7�+t#0�����T������9h�UkaA�7�)��WX|3�RX �d�D��h��bF)��e�E�������Dfo����@�q�1��:,���[��u)R�v�[��<������9W��[�/��D��>b��5 �W���K��R%)=do�����[����!�,��9��d�(8�x�|�C��HJ �QLb���.nY�E�T�noo�u������6��m�F��U
����9��B�*C/��z3�&W�t��d��/�oN�����Q�Y{qT�� ��f�<�7��P��P�~���0��sC����<���p��p��-�|��l���X�x&MQ��9p)p�#9�����+HVfSMT�5dy"������
#8�q��[��=�(��!��VRBe�r1��^�7���	��1��"��RY��4�eM�1�	^g�����"�^.R���4d�.����&������x�!*#1��@		��.Ff���FP��S-���0P�R�2_A�V�eT��@�Id>i�@��47�d�bn��`U���$(��D�Q<��uJh���������vgS.���|K�Y���]��Z����e���X�T3J�`z=���"19�(q��&�&��+��8�����U*�6�T�6,���A�hq��R	:���A���q^7�~��frb:�*�3M�����5RZV�6wN��yo�+��,\7���~��wG�T4��� "���)X��������<eM^�������UR���d�2-eze�#�U0���(v<�\��+<,x�����7���������<,�6�(�seX�J��@��j��xB�?��h�&��LB������x��@6NU�d�`C���#�������&LGnO�S&?�UR�SY������'V����T����8l���m�	�B"�h'���x��X`~E�����(1����]��82��HZ��r���H��j���*x��:���l��KW��M�w��W����7�D)����*69d��U���9+�e?��!Z�����YE&��K�-����NNb�`IA���IQ�U�5u�E��f@�����&I��C|��9���:}NB��Utdv
M���T]���3Q�`��	w����Z����YR��5���W�%�`m������m/V�Q��P���f����a�^�-i�;�N��&����hQQ-~���i�.��I�,2�X�:JE�J����;���4��Q�c�G�d�;[�b�
�]b����3��EX���)kt�%���6����;p�Z2
��s�#74��B�bNENv.-"l�[���^TY��H�
]]�cb���o{7��V�+���H�^�6q����^�����^�f~�������/o�m�t�N��6F�G]t���[P�|C���!��M)(H{��
r�����GL��������N�r��_��H~UP9��de����Y?�$��$S��
�I����G�;_d��h���8^���g���N���
�`�A�8�������.��l�Q4�&�����(���)w���.GO�l��fA�/��r����gu:b2"	g�4��H������e�)����;�3x��D�����8�T��#V�P0��*�r��I��2���Ux�X�Pl���
)1����bu37���|�L�;��E.�nts������V�VW;[rp���J�,!����

i��b�5�8����B0�p�o��5w�����R1'�c�9{���%��!oS�������;D��3��;���I���X
�*�	J�1)��}�s�P�=U�*�\u�����M8�����l�r����uY�ZB��moI���^u�K~nG`-c&��"s���"5g��
�e���������������&��R���=����%�����j�i���7�B0��]v�9�a�R4���IY��0Y�s���cOyB?�q��
�aA#�t��X:4������%uGCS��Q-��=����@����qS�8wEU�(�x�����o2��aA�	�L*��#D�P��g`<�m�����Bv2cg-��K#�$6� =<�M��Yb_�����3��^�
,1oy�P�����y�t�_��VV~-��y&�8������Z�sa� p��8�:�����xbd>��
��d4o��-$�����-�^�����((�d���@
`��)��&`e��i�o������������C��L�-e��F�#D?�`B]V(�)R|l;0�����b���K�{!
�
��e>��� 9�(��������fb�>]:	EW|K3�o++fw(p��j���L��j_)��xk|����S������K?k�|'���g��%��Og�/%��j�_�K
Q�B�]Ts�Ix�J�8����p��=y����[��u�C�q�f��"�`E'���Xj<���d���k���gd\QL`9 LO?�Ze+����Y���S%k���v��,9[�V�"���%��=6�����<�A�=��\@L_�{�do�0+����&�"�)����#Hqr��:�Y��y.({.�����^���eg��KVMb������r�W0��,����-J�q����Td���Qx-'��Ra9Xcu��I����h������������K�t��5�ZX�EG�9�������G����F���Y���������y��������S�A)�������td�O�l3�t-#��Y�UG�A���6CSU��QPC�r�d.f(@~9���� �J�@"��<S{ [-&���L���������['�f�����i���MZ`���J�q���6"����+�SQ����BA�H)
�HM/8�R����CkbDx����F�z�X��D�9v�x��>��.-I"P%��������6
�����I.]Y>�����3�6/K��M�9���eB�3[����Qa})����=�k�������k���k��f�UZ��Rj�>J=���`.���,)��4��z�:��$<�#���b�����)�tTJ�;�1��E+�n������fE��o��G:��Rr�XG�ih��H�/��M��QQv�G0������vq	�x��S<�nW�iC�+�1Z0$�
Q�b�U��1e
�a���86���yv*d+��nK_�<�T�;J��	�K�;>�����Dq���#EE�
�K�$-Q1�C�7�D2)����C�&�����ZJd0'�x�i������&CD��6gK�"�F
Q���#�{�V^MI�m^�]��<[�����8���U���|z�~����	����`�`&/�������g�O�Sk���#f��4���-�����+������3��\�t��Y��`��anS�[_�3?�`d���2��,��],�-����(gj���Ga_Bu�����\����N�U�h�MG��J�)
Z��z(������jB�&87�F�u�\o�$AH��J�B4W)�p4�Q`&�@/�)2E�W�R��p�^�'��2vBX?���S��As�q�����m�J�s�����c�����s���o����Z�7��~���2/`��g/�U�
�HT�e!��N|K3F�OE�LL�Pc��dg"��=aW�9,�oN2X�������k5�����O�a�WY5l!.�P(��i88&���l���;��,��%�3#x���Y������\kKE_
�,��� �'|��6����v3Hv����,���Y@���nl�Fukc��M�1"���g�u>��K���&�y��*V0������F(���T����!p�A�|�p�::�U/!fE;���.���7��e*�=�@w<y��6�"�;wR'6�����Y��C"�
2����#v����������ZAh���N`9��2�%'����_��-F�(j�7���9�!����>�:�`/)�R��VG,w�l�;�q����4IZ
Bz�['��U{�u�$��9�<[!x��B�9�8i��Y�r��WR0�]N��������^k"-��'#��:�����?�����*^6&Ov<���U���PX��a�8j��|�
�*�R8�2������TvM�E���6�]����oQ����'SE
Z?�E��	�hyv9L�z�,��./	n)����`�Q`|P��@'FW={l�q;8�D�X���x
I�U�
+x���W������xc)g����C��@�*\��n`W^
��lfP��y�%\��`��P��#�Ly�&�8'�r��-W���:���JB/�L`�-�o�E���h�������x��<�j�c)�x`{C�O�_��h�oN�=��qv����X�����G�{%b���C���p��_2����o��1���h;3�"
��O�z��Ep�~#�[����������P��?�B�Z���g�����C������%=^��m[���;N�6���<~�Fy���-�����%���a%"���o��%��F�������p�&H!U�sM��l4������,e�������
����; �q�D�g;��1�����I��	���8������g�7��G$�#�&u���c��!6Vf�$���4p]#�^�����8�G�$�+�U���Ew
�E�Ef���)�08(�r�]�B���d"�o���X���f|���g>�l{y����rJ@����k|
=��R��Q?��j�Z��D?����j'o[��_���%��������{	<IQ�KK���|*TD75����T�G8d{����q��A
��_�}�h�{vzP�r9&�eM(F-	h8K�q��-=���n�B7nF'yo������*��M^�iL�&v��k���k��@[�T�R�����d�;�JR#��Y���@�e�]��(
x��`�
�gD
��������I�q]��;0�G�n��������&Q�1���Ok�u9�D�}k&�P�2�DQ�P�����z.�4xC���b6/��~�����n�*���m
6�� �h&	��&�l�[���uz�g���I)�0-�K������>��
7�.$5%�� ��%QzN����.`ss���+������B�
k�g)t$�"�a(�}B�� F�����x��Kdx��>V��A����m&~��:�����Q���)R��7�kG��%����n�	��|x�RgMVI��#Q�U�CV�TAR~3������a�q�zbg���Y���`�:9~��)��X8Y�z��5 Z�J<�	��?�IyP=#,�#���|����[������N�����C��i-�O�O���DI-�	�4`Y�hRxCf���3�Rf�'�-��C@�_�ZR�c�����4>�����~e&�]��g���Ij�K
���T�p�f
(�!���W�a�#���������J�5��T�����7�/���W��'��r���vt�C��9������1f�q�^I1S,�8IV,�B������J�mu����8����(�[��w��m�����:��70������_����8Y���$5lKO:Di��sEX��2��v��>�m�D=������v�t��]!D�@����������!1"b�su�crV�'�3�b�?��l�H�Ew��d����uN�M�M
�q�������`��,���P�
H)����5��u_��@�!:���Z^u�K�dD�q.4���jlk�I"���}�Nh�|�	*7��������3Mw�c���i}�|�>i�������Y�&�>��_P��8���8�C�{v������N*���EY������3m�)�d�rF��#o<2j�����M�f*������	XT��8����n����Z<�,W8���``9���0Z��Z]�A�0�����HP�,��f���u�20T5���)�T
������������(�S�X2pBM+���7��^��DR������z���%���`��nNRdb1<���o'���@������v��`:������j����j!��)��N�?�tb5Aw��wY���tQ��P�4lD1��RE��'L�A4��I=T�u�L�0��8�p[�I��D���8>Mc>��)��)�H1��&�C��Y'B�%�p,1�9)��j�4M��vv������n��s���aH����;�q���?�L��!�uG��iN�1K���Y2�{�
:@����T���y��q��Neq���;=]"8?tB������F+3��o������w�W6���2w�ZOT]�\]��vY{�`F�>��su�z�b\������d���1H����,��Dv6Z�g3��2&�Z������������l~��m���G2��q��6b	_2�����K�<LJ�0�:�/��y����~yP������w'
�['*@K�`�q�Ask��y��������
��[,."-v�;T�����Pr�j�b�����	),��n�D������O�O�sxt'O5������j�^�~�m�
���P�����TZ���I*O�99�m3!�������u�n�y�����t�;�|���\X���KL��l]���(��������Vv$���6l�P
����`�w����gaH�X,�a3V+�W�&5�yc?&��H������%��,0��
��K���{y����|M���u���A��{�(*����Td~22/�	�����o��Y��E�l�q�������J�]K�-����NO���7�����Qr�)�G�J��c�����������2��_D1��|k27��+�j�T$���O�n$�2O3��]���e sxa���:�2&'������a�Y�k�WY��-r��82���ZF�Z�j�d2U`)��F,|�����"�Er��mA��vax�0����n&����7ok�����?E�I@���;c���_�Y&�����!��6q�~��l�vu���M2��3s����S��:��H�!S�6��2�,�M���*?��m��O�sk����K�Qx���������PP���P�]W�����~�=Q�+��;����\b�n�!_{����F�L�1a�%J4/Z��H���Q�S��p����N���3�/�"�����/�?�c���dP��u%�N��r[�>�!�"@�0��%ccu 11���h��'jx��9�m��~q��/kg�}���f.�y5�AP��l���!��hX���g�a�$l�fpw��P��p!8����\8�3��<�"���
�&j�G���=����u���$[�|�s#��H��vu��Vfyo�W2��
W(<�
�0�Y�������R�SJi���I%@���������pc�P2o��nL���1sqtfh8�m��m|N��@��"u��.�]2Z.���c�ybS���mWri��#�t�Bk���4�
���k�,�����nYh"0W��A=�l��*�����NTw>�	
�o[�������}����
�`�Oe��H�Y��
=06|��61g�Gf��em���-�V
3��x��������B�����N;���������G�Zd��V��I��>�&K����F� �8LY�E�Y*�&L��K�6�3:��'C���7^��`rmC�$cP�k�h+f���6���M���G����p<������T����r��3dD�8Z�qCZW	`Iu���tb�X10����_�c�=kuE2������\o�A��y��&�����p�e�?�z�m��/Ngr�	�y��H5���z.�O��(~�1�
6�l�
�'������Rp�Zc���Ey��'l�:@�W���f('m�[�l�B�b?�J��������o�����I���������K�T
af����������d�����b���
�|C#H�����T���s��<
�:[��Y.Yf���uD���Q{
hJ��3�����}�uc�T(���3��H{�~�U��
Y;�;�k��b�'L�����8P��q�6�`��A���&���4����V.�����'�&^�V��}�	m{�|)��3�O�����X�+���1m&����>w8'�h��%+��Q����:G~C��8������K�%b�)�T��p�#�k��1�u����F	�@*Y�+(�M�dLi?����
R���;L���n�,���r��aCA�"	��Q�����H�����;���:gp���^�P���Sc��"m`����]�Ag�����L���l|�djm#���rfjTr��e��:�Nf�1h3�����Yt�L��I�tsC��c�����'��������'��z\��>{��*��8M���i�����"ex:���8���W�_]qf�PK�yO���%Y �X���0�Is,�q$�nRE��y��i�������iB)1���� v�)��y��)���+A<k��T}H���������f���=�s6l!����]:����U�Z�}��Ea����V���$I'p��q:����R�lT=����^j
���9�p��g��y���&����&��$�L�';���GU���������wNM�w���]oDb�����1�o�0P���E:�b-\���b#��#C��#���0��9������Z���'�����G1�cK&�;L�7I>��I\�����������F����$��31z�C��,/;��_7����9(��^cl$�P�F�_#_M�^o��K�p@��u1m�\�H�V�X�:C����IMmP4p��9��C�`�fae+�����������=�!,K��8l�n�c��v���wn�����S�#Fl�o�(O����A�V�E��wxL'��P�y���F�	q7G��G�Y�as�SvI�n����{O�&s,���X��48c�.�Q!���E��S`��b+F)3�l��\F�S�H�e�$q���I���t���G��$Q���j+KG�Jw��[�J����Q�a��U�)�MhP��2��#��d�#s0�-���M�C>���s�$��������$���S!���d|`�m�20�k�W�Y�9n<v���{|�8:9n��9����Qc�/�84��p8�^S�����>3��j\�V�������-�O��fgC�2���<��h������b���B�O;�I.�-�mD`&d�&F#,��%!�2�c(���.q��7jSe����_$���,��C�9�D�o�i�XG��j%+�q����j%4B��h��w�q'CmL����,z&��%�����N;����A���u��G{��]�����9N����L�n3�`f�l�y.��rN�p��S�`��q��%Y��~�����	�+����Z^>����;��@&am�.'���ku'���W:�]\~��[�Y]�<��^Y�$�N���Z[]�����l���,--M$m�c�d��5���uA���*D��%!e/aU�����I���)}><��q$������aV��fvO2\�He�"(�zQU�����/&P*����%���R@���������$Q���v�.{�n���N?��&�#���xy^������/:'zg���Uf7+o��Ul/uz_����x �<12]{�a��1�n8�E%H[�s]{���2�����C������|x���Pv
_m�����H_����_U���mS����[��-M��LQ�8%)�"���%6�����c7������;�~2��������jOL��}zFl�<W��$sX4���#8WE(���vK�C5������	��g3���k��Gj����>������ms3gP�/G�=<+iD��=1��23��*\K&�H��3O�E�,)"�3���^�V���s~E���������F������������>�)2�'�����[�-kY58�A	�nT���P�0���������tZ�)��[�L\L���=`����A'a�t����d66)s b*����%��r#97�<��c�&y�����
�����4����[�a�ez�CM�����l;zh`3R<:l��PC+��PM-��v�3�����L��������c�GXT�
?��	Z�a|����E	��C��
Q�q�xE���-V�?g/�*~C�]
M��H&�&��n���}y�<������og�J�-��6�v8������S�k���C�m4�ZL������p���2�	ZY�63��

,6pk�x�>���3�%f�t��\������,������}��`m���������&��1G�$���YqBO�Uq<����{�x����W�����$���
`�C�Pr������f��bLb������i���h�oT�_/WfH�&/N�_5�Ov_��6��}���v������#7����������
���v�O1�_[_���kk��u�A//}�ci-���������m�+"�tF���mG2[���;��9hj�w3���>g'�O.8�=u�7�>�IF���ZvT@�2~Ik��l�y�Ki:��]�����0�0��E���s�����Q�1�u;AwL�%]��5t���pj�e'�[{Z"����9e��g*��/"dV^q.2�N$�p����/Sbz`���s�Q	wPE5fd>c����O�]Cc���m�w�Kj
��
���1O��]�
g��Z���R��[���B�(x0�V�G�S�h���(HtP�k�������]^�=v,��\j!,��T�%����PD�qF��3�&��#i���������Ej�e�������se88}�Z���p���-*�lC����	�$��h�8�z]t����������)��w,U"��Fn��m0�o6�o�s�	�A�V>&�F�r������Q��fG��VN��YhIc��c������{�G�v�l���q�(Nf�H�������d���a����(����HP4+����V��������5��0
	��}�lYD�$\V��
���8������f����k�{?c��Q�jT���c��2@+�������+�W�D�;��2.�c�/�x��R:1n�('�I��X�w��#��q����Y�<#��f:�)M]���.�������k�������n��8��� ��N-�_���m E'iu�=n�Z�w�D��_]������+�N�b��������|����'}W*��]�� Z��D�kk���[�~��2�����ylu�&�������/������>�0��M�5Cby�uv�y��O��NZ������:�����o?,<��}gL���R82������0fsWi>X'A�����O:}�
��r�IV��@.��7
������dr-i���x�+	L���i�CNH�9!���������I��p@�>d���#��r�hA�N���!\V�Bfkl���4���S�X����xVA�u�$��8,��W�Q�!m�JDA���.)����&5�����6�������T�Ic:��>��@+;s�H��%���Q��%�M�.5qq�Mw���H�����O-���.��x�r23�,�I�w���g�I�*$�
�7�?�Z{c�=��y�bc_:���"=��c~�<�Oi:]���xr�I�CTV�{���x�MTvw���c�?f\���[w%#a*��Z=�����E�p79�@��H,�ovX�����	�S�j�~*�B���(>�b����V=�&6C"��(N^�&Ke������D�\=_�9X���9��K���>
������p�������su&���J�n}U�����������Zt�o���9#R�e��$|)����Q*nc!|�1�j����6��'�������f�m.Ef�W=!�^�\������&.;!���6��Itkr�:+�`�0������lim{�!c�N8H$�(y�d��$��rP��	�!<������'g�VE�C�&`�Az:(���&S>z����~WLn��t�5-m���*[��=p)l���cu"������O�%H��p�����q�oQ
!#$gck�3�/Z}{5��1���:�0%���mHjU�h}�{������y�������[�mP��Xc-W��"�t
\e�h����
�����7���izTy�����7h��;�I��������ZG�mH��<�����<R�
f�
���P��ef ��=�7�v<��f��X��������e��_���sE@�#��{v��F�
�BX����z��K<��<����L��,�#����uA������������	H�dN�����'��A;�2����u������`��c2�<V-p��Xh|�UP�&�x�q4F���Q.?9��a|n�!>\�C���"T�l����C��3R=��)���x���r��������r7:a���� c����An*Y�%W$��F�P�WL�
���T<g
O�!s�5�����������������g��Kn����?��9����IF��'���&M�e���,8�
����7��^\��:t2�q\_��D���'3TLi#�H9J��G����4�N���S���z�W*|�m��T����/g��<��-��-���=�onFA���u��zi����%��0�������z��o�z�,U�r�WOL����!�����ED�6"|�����4�G���N^&{{s���f����qA���5}���L������0��:��]���X�>���}\nc2�_s��(Y���&Yr��O�a�� ���t�l$zqe�]�[���(M.��e��ks[/
<�/�5g�a���p�O��G�7|}uk���\[@���?lM������1���RW��#z��{nk�����ZykuB��E��m`U��$���c5�D�v��1�29E��
q&��KM���l��W�	���Bz��y�X=eD�Rf�-u�m���jr�
�&/��������S$)�!T�D@��Q���������X6�Fp��c�4,�zF'0�_�[qS�JF�H'�)�T\��~�T(3�dA�bH!M>��I�R<�~|�����Tw���e�Y���fM�LA�f��<?��2��Y�l4�z�i�6���h�?����^YI6�������^���z���3��uE��_�A��M��h�N��MW����=����K�w�������
�[�y�`�5��R&C�Y����������X���+Em��7H���c�d)V2jM�r�U�Z�a�����;X�1������}i^���X�@Ub�uj@
 ���H%O)�����?��=	����7hp)�Kk�'I1Xgl�}�O7:�g�B�n�,���<v�b�q y���u�������g�������2D��7�]�[-���DHQ�����bn8���	�N�V��.e���q%����'��������j�d���������FM������s<�0g��JBq�]Ll%����8V�'��h<����m�[�$�
���1�!��pE����cB�����[��E6��<��i��K���U���Q�7����@��t�0�<+�����{)�Q�n�T�5�u���N�[lx��J��DJ����r��a�j��H�X�����_����_��W��&�����S��_�Eby�-VY��B��1k��e�+v���|���/"� ���4�N�]�,���e���1$�{)Y���A"8V�Y���d
� ��3���T��m�z+�����%�I��.�����R�T�Ghj���Z�Owr�O>}^>������U���0��j��=�0O���j��LA!^��qMo�l��i9>��8���lE�=����J���e��9Z�T��Iq	�(W�G�C(������16�^�$��fc7Ez���>2a�S�FE���G:�`�b������.��U��G2��P��L�e��\�D�Y''�`5�p���7��	p����G+��O\wQ���[	������3�E0	��u��mvn�]�����a5w��b|�T�u���p��,�x1���f��8^��W�������7b��{��
���'������4rN�h0�����o#��jDa�������q�,��0u�����}�r �����az�&
ix5��'�!�H�����6�~y#7�Dc�r��5��5�#����
N��e){�oH0l_�Z�JT�X�
`l������>R4����*�����3
�H�b	8)���)�C2F�h�(�Z���Jb ��(�;�����*�)�����M�!a:Nz���������P�K��MpRdB���A�	�s��*�s�� � �y�k��Jdb�]���j:��8�]"���HL��Q��f{�t.�ib�+Y�Hgt�;;���
��OG����KI�������Q������x���3�����D�J�I�����~��Y�^��1	)�������`r���g���E������+K�u�4�uB���FD"�ZjQ���K��#w�d�Q~��L�9	�fga�k���0�w6 �$f�r��D0=n&��o���a}��h��� ���ntQ�>�_+�`���]*�^���H�M��P������'��<��Q�����rO�����0��C����3E#U�zG��8�"����n!�x6@�ykYa�w��>�e��^��Dd�i���D��V�o�w�x�R4��?��x�r���P�����zr����[���d�h��$yr�k�Y��}k�M\J�)�'��~����T��|�eD�U�)G�0�N��g�������[����S�;20�XBC8`"�3r 0c��m��Bix[	E���A�>������k|������.}���8����SV*��R\3E�Hi����n
K�s'������w�_N��7&z��N|)+0��48o
��������^��i���	����T��:�a
$6PFppg��
�HR��Q3
������S��A�:������\ZO�cJ�T��:�>�����������M�&c�v)�.t��v�)��,u���`�	�n�`�6V��a��$Hh���"mP��!j�k�N;��s��������6����vs(Qnr^���
�����H���*�Y+	���:��~G�7��Daa����j��/n;g�	�l0��z���M7q��!�X��v��k�}=w;,��2�~V�`KF����2\x<kV��+*��H��Q1��'������P�*2�]�!�~:\��|Es,�;Q��cq<���2=z]c��2�A1�����\zy����*@��U�Y��L�9r��I�V���p���7�V��L��"3���c�����[�c�,$������I2���'�>�l��y�{\m�Lux�L���1�)(��?�E�H�P%F7�������F�1���� �0�i��'�v��Q]H�c���5�.'�{���~�a������=���`z���a�cE������`J0�F�[ ����O"�56���5b!Q�U���a)������a��U�n��f���h��<9zSf������~�3/ud��<,�a^4�q%M�N��ub)�O.�7��y�P��z�0��}��/o"�a�;<Iw��^��x����d;����9�*�b���o�l!�W�p���K���������*x�iI��d��5=�y�T�c
�����u�Q��f�6b
��&/��=����Mv���?����=~�1�g����+:��aImn���Sb���:�P���g���}�$�^q;�B� t@pgx+�-��S�2l�T�zZ�V�am�����Wj�tU�,��X�F`Q<g���6uleA|:+����4����� ��Et�by�K�3~�{20S�y�?I�RC0�?5�m3gQ�)�6(��B����p@[���k;�P|E?�-��)J���*s�-�I-��Bj�0���X�@V5�SB������M�zi ��0��g5���S��v4�G��SI����V��r�w� H��'1`�P
��X���Q{��;��?�I�M������>����+��4��������04J5�8Q�4q��m�������%��j�9A&x�dBG���H�,�i/5��UF�6��	"B�����G��e�����������lv�b�3�8�M����]�O���mE��9s��M�&4��s04�ot*s��=�y|�7��_@�N��8%�X�}�9� m���'�b[�?,��uS��EC.���m�x�)��L�t�b'f
qJ4����I���+^r��37E�"�w���-
������ ����m�fCc�%�.��9E��f7����j�v�G������_>v]�p��b������*"�2�/���qn�k����LN�4�q����X������!����]�k���"v��csV��=�4>s�������#�l�&���"����0���1��}���o�<&E�J��}�0�	��]����N[����9F�si3��!�[�
X�T����5�<��r��E5Pi���\����(��pR�O���O��%�f9O�EVjIdf���8{|
|j��X��D��c�e��f(4���N����7�'�3�w��#_�4��>_s��>���q`��wt`J��Qk�C�4�h
y��t*�=��X?�T�7��Bm�^�jL��_��5�B:u<$���|x�Q1|@��}A�+�Z���63G�x���gy�����B�O���{��"�wo��Q<���G)��n�!����W��6���E/N`�������}����*�L��>�i���U�*���c�����[ Kt!_�jM%��J��F��������ns���qj�$v"�c�/��d	�_*J��<�����R3yM��d���'rP���G����:��,�_��U�F`if�$`������e�t����8����BVTF�[kX	u#|����� �B3k��y�����&q�YN,-
��>�M{�7�Kw�R�����{w��*��LV8A�.�K�_U��B<��c]V�j'i�E�r������xS�l\��!��R�UM������%:9��������/6�PY�4�����Y��0�f�xo-!O���e�i��.�9�=$I-x��^����A������:N0����{I���_�u�T���}�Y������s�q2���5ec�72��5��^LglX���
U������lx"v����e��k"b|�34#��?�yn���w-3���yZ���]f�@e�X�(�\b�XR��v��M.%j�����8���w��JL�}A�_������k}rv}@	�y���t8�Z��Qd`PA��;����DH�L�Q�e����	
�9R����,e���Sz������1�nx��'�.Lv�����=���r�'rHX�r'Y����/�&�"���.+b���{�
��i�p�����/#����u�:��� �J��?�����N��D=��
y �V*�r���6��� ������S������W�����/����M�Zv(���cy�jL���d]�x���~�����6��c���!�NV��$*�dMz03)���Z*�y��@n�A�r��k:�4$+Xw�"��i�O�#����P$,%�X��v\�0����K'�RGCl8��o.R����"Y_�����b�:w�C�J�9�I��e�x;�w9���g�+k��(Ev:pF��6��>��aO���{����b��V1�;�E��M���<����Z
��k�5�������{������"W�[�d�:�������%g=�\,�������7�gI�����1l����G�����O����7Q�
}2����n��S.(��&�q���=��qc�h���+��x]�M ��_�����K�U����i'�+��^�2b��x�	iI���jYz�\%��1W�M��:�/�Z"C��`B�Z~��m;��%�ev����#�������L`P�Ih[N������-�����
���}d��i�E�k;�H��M:5��	{��^����:l�cRy��sJ��y{7�#l$�]�f�d�l�6�6�?�,�'�#���?�������Yb:������C�@�@��Z���d|u6����:Kh����^����5!4�<2��=J@�|�o������~��Ns{����8�?��,�.NH�3\�{'x7V)��C@Ak�3n�_�b����5r�u���X��m�������Z��^�%Cv�o��*x\6N����g�.�����cc�%p[�g:��Sl����!���N����iZh�w�c��h�O��P�34:(�V�>�	�Gi�t�^n��%���F�}��$�.���g�'��#�����fF��_�>���NN/��R�8�6��`PA��M=����7�`�8G��P����hXV�J$0���$���Q���
;��jP�=���~�qJ/��6�85t:#'�b���~$<�����e}mm��N�rHVX��u�����b}���Y���_�%Z���lm��EP>��cd�
?"��3���Q��J�k��z���XW��A�C����F# :qXP++�O1�X�una:#�������0)�j-�D�0���}�~�2��O�K�<e��e���Sm�'����s5'@���y0��/{������6�T��m���eE�GF7����/���DV�i��X�
�/BV���
+�z�@������opm{����'��E��{��/��S1�D��qO$4bl�{����4�&�qv�wlY���.:�~�Gn:d����CSQ�%����8������L�?�����l?�C�@<�).Z�C*#������$��c�D\����"�^�Q������Oq����<y7��=��9bSD������$����������a�xh���������[��:"k�BV�JVc�"HdkZ��\��8/Q�s�+u�(.#^\���p�4��g�P��~���D�l^�� �}�
�pW_4��-A
wvK`#�B�Y2��Y�tD������\F\j��Y3e!E+4�VY#���@��/��h�Hh���cc�x�Y_G��0
�����e��?�$<xh@>��C�1���sF�9���_���T�`�
����qrvIaj�p':�u]�=�f+E��>�I���%{���+k!c���l��{_�s�K����,�`����/��VE�������*JTQE�U�N��8:�=��#"[_:�����+I����[�++���~��i�,d���4dR��3�P��K�q��sr�![J�e���8]X^�l�L�0�d��Hr3��F���c���������5/�7�xHZ�S�l'O{��U�eR�v��<�N�3c8s��v+M���p��q#M57�k��d9qk9�OJ�\������C ��M�QaO���]�wZ-:��<�n�+���['���c�}x�H�QB����?����^���mmQ����ub��	�6���"&0�?��������N�C�|�\g[p�X�����~����������e��94��t<M�����-�o��������������[!�x��^SO���]�Z����~�z7io�����O��j�4��_;��D� �C���6��!
aK.���r���JI�Zg��o�����*+*����!w�8�g������.�����D����
Mfd����H��K�'$#`��t���HY�K�v��(:�7}������ �{_4vU#��'dY�Xm����a�X�_���\��P��O#	;U<]�-��������P��3[��h���:�K�Pm"����@�yu��"���6M����@n�dS��\]�M`��-��"��]�L�	�������H��xt��
&�6�?�"��>������$�'CJ��	d
�
�����P_D�6����rE����:��������ex�c	O���c��D�VL�8��v?�����u����H���y�{t�=�'�-�
H[�����v=>h0����s�aN�X�#G�/����5po��k�}�1�=rb��^	u]W��B�P�}���`�%�����?�M�o�������d�lO������b�������{H
Q��w>��-6�Wzo��5XQhc�R�^�L�A)�����+r�	"�98���:[���5&�e@�(������>{��H���^S-�~T��`c�-X�r1�������5��D�sWW� A�Yn�`D��}������G���bu	c�Un/�b�6��*rX�AF��70mXY�'6
v�)/l�#�n��������d����i�}`�^���u=6A�7�6����(!�h8��1ML��MJ0[��//���P~��~���>K����W�{`��2 �g6#����gG���H��if���j�
�u(^FM��?��^�.N���b�5��rI;��9TE\��K� R����'�G�����]+��+�����5�J��
�b����6�M@���3��jG�2+�=�l���_0z�����A�Jm�`�
[�uMC����'�-qN����U����!2���vOv	�S�;���l��������`�v5O�o4�~�}	;�$���j4��R�a��`���3���	�Ez�|�W���m.�
O4.w�w��1�}�2�g�yJ�vt;�O+����9�^�����������[?fvB&P'P�?�������w2V��W\gb�x'H�u}���)|�'����=��B�k!���]}D�i�sG���z�9��n4%?��zR��%�5����j�rg�|@�H8&�`h�����������zw���nru�8=���W��f��::��]���LxTgH�YQ�������k��B�����7��&6�K�� �te���I��I�zN���U�����(�;���P�5t8;|� H�a2��e���9��2�	�]UW��we��~I�Mg�M�wu��^�����oUu�U��^����}��xn+xe8��i�9%O�t��o��L�.������G��J���LK�3}c���`$��������\]i��BK��>^$����9e��K��(5m]�MHy���k���������cH:Uo���
=>:��S��j�����5��[uu���S�0y�������u����C�
2����XR�3����f�yO������gx�o,�Amy��V�����d�����J�w��=��VU��O�!|��*uO���
����*���
�h
~o)u���SyU���������\N���D(�*���k����
����u,3���	t4H:�����'��"�`�����������5eB&���N+�0�^���j����
(��� �P���s�=E
>
���c����g���[�>/2��RT�	�c����!=1V�M�Z&f���������NO�7m�;�Q��N(b����t��t���u���1��K)[jAk�+ �����d�|�x<� iqk�x��G�g"ht|vIVRTZs�����:���|<�R>�{M�
�|�T#��fk����p����R������%�R��������R_���{���*z�(���o
.�������B�'\.����.�P��0�+�?���e��~�y����l�^������_��w��w�&�����nfo8�f��vjj}u�!pJ'g���_/����
��j��#:�@�G�����������]�������H�[eX(����x	��u��+ZV�k�l�T�o���}o�o6E
=mpF�[�
��M^mO>���^P�sx2�������
��R���t���n�H��w�)@��D���;b��w�e���OcA����,��nj��hra3�_��x����(���23k��+�d�Q|��Ozc]���1:����ho���405��K�r�k�2���L��G
�z:��2a�,G�hX���������)$ ~�!�_���?x�������G����9���@t�����E�+��f8�� b
(�%�qo�Y�����w� �C�����o��_`�s��ax����������.�a�BH/(�T:��l�_z1��������{���O{����-�G��{(f>�5P���� ���af�������c_��2~�g��� k�:by%��p����By�E��K�X�=N=��j���Y2�H��������8O�n@���~�X}?4��a�$�`	�O���Y~�@���8r�B[���c�e�R`�ON���tP���������r��V��|��t���5T��,�`�
^6-o��Y+^F�9l2���hOE�6���������%�<�C��
����u�-q��������	A<�L�Aob{��Ss��d�����u������F�#Z���*,H�M3y@=���t5��F!a��['�����j�3������.lt�}�3	ab��u��[��$�{�(���7)<2L�Y�1�8�[%��@��0�P�\~�������]J�C�aO�������>�S���P8�)���&w���j�z�o��y`,!���8
��d$AQ]m�e���q@c%��Zb��X�T�'��qS/�t�
�T�+3C�d<�`�=�����"�o�4~:H{}�8��.����6���&�S�����'�|���}�����3����$r%�1f�Z�#��)�/���nBl7N��������q6�+D��'�����~���
o����Yc.���:��i/���Z�`_�����u�EG�{d�62����2��c=�NP9��W�^��ml<���Z~�{��+W�Ey������=6���h���������&����F���v4���J��>/41_G�����IJ��5�����Wt�g^2�kH�>�S��T=�"*�9h��D ?J��~m��G|����������Ej�Rg���aT���M�9�R������j�k�%���#���A&�W������9�w���0;p��L�x���w�����/�8��7�O��9H���D�j� ����6:}��	���1���U���]��Tr�m����������*#�E0���-���9��Bu)T��^+�����0{�����W5M0�1����b�T�������Qg�G����LPg	��l�������E:wM�F��6Z-����7������{��e�T�q�L��ZG�}2�d���~=��������rp��$��<"3z6���#��xU��Q8\�%�x����v�����R��E����wb�O�������y��*�����z"R/����}8�~�^��^��Ks��H'�u+����n�h���������_�Y��/�'-��~���5W/���\�
aTq���Ul���;�D�3>C����T?s���(�`�FE�4^��@��5�i@���$��B��2�i�S.��*L���]�p+4��8{�S��R���7=���<
��T@$��y2g,\����D���/���`=��e������}�R����Zi��b+:z#���
���c��f�
��3oL�a�q�9��V0�@4�`���Fk4��w���=��|�8}��Y���Tq/�����F,"���(����$�@�2����M�~�vs�wmi���� >k&�c
r����O�~?B���~������� �"�@=j�K��:N([Y��4@>:'���~�������9
���q�3��y�-��Lye��k���G�8g��q2r.&w/L���(-"L;���d��&�������o����v���J�j����V���n�������D���.)�tX��h��Z#�Z0$*��@j�p�ez�F$�S�)s��jm�g��<1�������D�����!g1��tm�g�D����g�5N���,f�&��7�z�8�S�#�}�i��{����:��0_�7����d���L�]>�)��d��^4c����43Z������
f�E`e	�����w~'��b�]9��`
�c�\��M}rzo�8�\�1
W�B�WS��A����&�o�4���s�^�4B_>Yh�t�y8���{I��e��QZ(�!�<
�������4����H��J��K���{���#��J�����9��;��_s3V���wS^q}�X�VW�k��L�- ��zVz�8���!�n:{�E!��>�@G<���9���!�v)�����������F 	������F�M��Tn�����/�SD������J1��RE�b��X�(�
�{�2���r��M��?�Q�0Y	����r����?�d|�{��w6,��E������q%K=�.i��k�P�����>y���U��@��<�B�UwZ=�����/�M�������������W��Xp�D���3�X���P�2�C�����������i���#����P����"���_��A8�w���jq7��,�7����R]��lW]��4�2B�=���w��1����X#��Q����F���?����L���>X�r��Jd}��r��V��!�l�A�C���\��T��rkq���$W�>/I;�QB��U��H���z%��s�v�_���h-��W�4���2���KH;K�I�l��5��J�G0�:���eB��Z�@�c��l/�-�6��0���H���C��.lEf1�l��i>c�ON���)w������%���c��y�?R��{���hs%dJe�'�"Y3��7�k^9�,�SW9u\��:�c�.����[s�,�_jonr��|�@Ixsh������~�0������4���?w_��AC��M���M�-�/Rw��VDk�F�}���+���oz��=�7�n5^4~j��������`4S��/�������W%{��Q�?���+��GG�ZPmN����x���_F(��\9a�x�[������e��o���>���~[���~�b��o<k��.������}��\��M9g�j�>���]�c2P�eB������{�r�7w��~S��G~�V�?c�_�6FQ^���Er�%SL
���e���1��=��,��@�^��/��PQ��LO3o5���x��t�D�O��U�v���c���p��Z�O�u����^	�\w�s�5��5�+Y�0dh�u�[(f�&C�@Z�dp�2��0o"��/�.��w��a�3�c��
���P��s��zx�����7�t��j��2���E�*�{�s�������M6�af��p��Z����7�����g�?!�R�������?�n0���,s*�O>�18���sq�'�7�w^j�{�i�Q`�P��F���]��)]q�����Q���Z��:��g��5���N�"u� ��p1�t������jn����u"��a~w�����n��axO���CM��Y�8�3��Y��Q�N����U-K�
�V�D��|~M�I�� ���<����R��;�4���������i�1�)���N)�g�z�.��5��!������h��q�&_Dr�m-����}�\�/��e����s��
z�T
�t�n6��lpwb?���x��)p��w"	���7
�1��?�0\^�[;r��%���p>g��K�V��6+��������d9?��Uce<G���5L&�������:���*>��������}�����_n�r����~O+hj�
j5����_�U�:O����B���hg��O�����<�K~��+��M��A��`�~��]��{A�a0����P�������x�k�t}+���[�[�Dh�`8i3:|���������`O6S�d���g�n]	l���O�:�9��<FY��8���������[A8������2��������>��[&�.�!��@&���Z.�S
r.�����]{#z��� ������Q:I��,0I�����������&��F����
����@���D��x9����3�y�����D�F����a4+�	����C���*&cz�X�V�5��j���k@���<��}V�{��\�U��`D���G�X�tF��`g�9����@���W9{G�zC���@����1��!?�F�G�<J�`?�v}r^l��C�d,�,����v�`��	���y�~��RC�+46a�J1�.���i8&�YZN_�+�6��n���E���c�?K�l�k�������F6�4��o���9A�b�Y
�s�2,����E��a�qg���(��*���g�eUS�V�K���������������1{GS�~�z�;G��Y��� !������z�m+����y|W����H��
�CG��T��x���%��
����!���E) }�#���%�8f �R���9�P�������<R��U������NY��9
4)e���-�o�k �k O-�q������)%��O������7m�� ���e�1O��Aj.O�Z>[����}T�����s^)`��"��*0��+%;��2�y�t��E
�V���S_��q�VG�Wr�D�����n+�$����J���rd%
���7�-�STF;[T��o�|s�x��-n5����l1r��������f�����2��r���-�,��0<��_��"��U���V>nZ��y�;
lba���E�-;���Ax��,[�Dk�0���s���_.=��/?��A��R���E�
����.���W���r�_�L�]��Pl�P��������8+y��K�����_B;-$�b�-�v	�.���Y�j�������TX�	��w���,�YIl�������7Y�a���In�������������YL�����p���:���$[U��;zm����)�qoC�G�a���9�u.�'+@�"�*���)O�c\�L�\S�)h�m��o6���m���s����g&j��Cw�kJ(���F�F��#Cl	������*Gh�'�����5��c��XH�>�6;�&L�6A�V�h	�i�L�:���k�)�*�#}
���A��>�����|L:%�UK�R9�����;�7�Y�GqWo�nl�������/���P}����P��)m���I%����(�b��i�8)fG���\'��@��sx���u����.&��$r	��5Y2z��a��z�:v^J5�MD1X�47��3]=�j��GG�����V^T��\��3R�(���o*�C��5u�z	%��f�i�;�^"����q>m��6��P�0����	���I0^�)���$	F�q3;�Ak��3}�(d@1P��m�=-	��g��1������#��i���G1��/��[�Uq�
����'������=�u_�&�0���J��4�w�p4�~0�9W�.&�FX���Bp@�������fI�cRtD�p ���}�}Z\
L��@xs� ��$-�����s�pN��zc<����R�N�\]��$�,����u�8J"%�B������|�&��i���*�}�	�.(�{�<�������Y��dfNp�13,{��_�kLo}E-��f�0�l�j���z:}7�������2u��3yD�����r��#i���GoC"l�^�q��1<��Fz]�������;�`/�`Pe����3�ve�2��E ������wk���2�H�7��H��J�,�z�\{x����=��/{�(�r2� �����qk4�q& ��R��~�#���f�9�{��������:C��t4���zL���.��������9')~��9{�.L�����������
M��XM��i�xq6S��d�%q�z�l=ao}z\	��
|	�uu�1��q��n��0�+l%b�C�-�Qa�2JY��!�,MW`"S������A�87�?oI"[P#�h�v[��_�]|s}�-`��>���L11���b����q�{��f�`�?���Q[d���#��8O#��nk�����L��DS.J����ROq��t�������B�~�P�Y��`��I�Bm
��9�)�p����%�D
���Lr���vL��A�[�U8t���a�&`c�c4(�He�D�3tI!\[���8��z#�E���*��*I�����A��Y��B_���U	o���2��T���H-��4��ZP�J�X"L`�l�6�m%��M2��p����x&y������wP�1<�7:kv���|t~Nw�
�-�����K9O�'��
e�d���:���"Z�y��������$Zrv��~���-�n�-���y+��r�]���W-L?�����+
�����g�������G��6��^s���������������7��!�3M�� �&�e.����6�N�.l,8���������xLO�vq�&�Ih>�������G������5���������������<�n�������4^A�J�
��1="��vs���e����va'4g��M��xkG�{��8a*"L���~�{���������C�����E��������P`N����I�d�U�$�&si������F
�+����Vi"���6�h�Ry����dD�W�qm�u$I*y]%<\IJ}��rW��o9��G���lK��z�SCW��3��(����4?w����/�fQ
�����r��!.��C[��W�@-���W�#Y~����]��;�
�h�j�l�����M�s�;Gg��
kV�I�Y�S������g�nN�B�K<���������(�����ry���c=����(/��#f)F��(L��S/�V+��D��|K�Y�d�BL6DN��vZ�[&���d��I�a��b<�c�z#-�6d��q"���FB2��dq�r��Ex����f��;!����o^m�V5+�Ck�qY���i�	X`�3�a>X�u�_�E��������w�D��+�\�����������w;��{��b��rv���=_QNzxdY���$C��)x)����,��cG����W���]��`��1����_e�k���<���	�K=��/)��H�J������St�>�B:����{�%�������(Y*ei�'=i�i�[_
�	o>���|�#I��/�WNi=g�&����������V�d�)M������!������(����o~�yi�O�#��q���E��&^-R&���L���Q��Af\13���$���4��I&���o:��wm����5��in%���
<�� r��1���%�E��$�ptHO`&6��9��	�PzN���)��q&�G��I��j�� �=Vk�S�=V��&a��Jk'�
�yZ$c4��2o;3l��]y���O�E���vW�/�hJw5��V���������x�O ���2�#I�����Z%K��-���`�-�p� ��<��T�93w���9^?F�p�VP,��n��a�J?�~�p����-cO�W�C����?��An@u"��3X���'�GD��,�2�Y���#���������)M:��c)��[��N�{�.�E����^�L���0'1w��s�&������
VA���K��GZ����/��w(���x��>����c�lQ?��SF����I�R�K�.?�U��^N�,j��t�����t��(i�yI�8���9�T&3�C�j�$\%��ArX~�$�T_�!�c��4�����=j��9:���Uj�����C�^z���8K~V�f;�����ulf��rq�U�����H�-��ZS�O��E`fa"e�r���f2����rf�Q�GVBz��o���Q`X*��_36b(jY�+�������������y�O/{�._)Yk�R��aq�����=���*n�<���D���$����[���wL���_T&�a5O����	^?��3]{K���1�0�t1f]9,�g��>2R�>���s;�����R�F:���A�e���������Kj���b�P����Y��A�����;Kz�L�j��L+�'*�xi�	���9���\�C��A����+s����l��E��)g������MgoP��`HT�j���f�����*1{"c�y&0�\q>��������q�������7��!��K���>��h3�u'�D�9o��a]fR�*I�g��#/���3����J���"1)�7�1�M���a�h�����z�.�����tl;�C���$^�!�73N�S�_h&��dA�/��"��uq���a?q'$�����Hq"#:=�S-h~3��p����dr>���$��=M=r�$N�K�Y���p	��}*Z*x6�b��e<�����Y�p,K=�0����#h��������>�C�&$2�����8yG��>+2*U�a�gp�q�� ���h�s�U-��{���=(	nv����U�������C���J��a�k���`���v�����}��R�!zd����An!`����������?�us��iJs-1�4�<��
k��#6��p�S���'�����c0E�M �.^��^�nh2�T���fr=�u],8y�v1��0��2op<xn�_� ������d�5�W�}������+�:��z
}�'t�����5=]��6o���(9�M�}�q$=]0p��L���Rj`g_x�^79���i����U���U���/9�<�v�'�)]Y��~�@3��r!�T�.i�f�4�o^�����e�	�������y"����I/|wD�E!X�Qn}Rmz�\�6!\b��w�t��5�����n($cl3���1��i�C��{��
_r�D��,G��'��rI3�/=�7�_'���:������_|��V��{qo���We���������`��krm�	��7��@�1@y��?h
���Q��������o�W��c���]0�+O��1���H|��?����`o������1��di������f��O��k0�C������V�j&�
�M������N3��3��2P]��b@�#�����9}a/�<
���1k�gY�M�u������
�]]�w���<���i�"�	����*,��'}��
G��k��ldT����i��h_����auJ������������W����%el������*-�A1�Z���HY��	)������N�@pTq,�JiQp�J��5��W�=��������[j�8������Z��9��#9F���B�?��2���f7I{c���.Z���,��f���y/�J�$�Y��s����C���*E��1�>������pG�e�!-n+�=MScW�b$>25��%g-qr����������ch�S\�f����6�������O�a�;��vOe.b|�
�=��?�&�`aB���K��-��Vw[W0)X������Nm��6���DC�]a�6�������z-��dg�O��_=�(/EW)������H+����l���`&�W��U�n�>=<|Y�a�G�	����]�:Y�V�gvC��K���~+����\�A����a_�[�~�o����x�5r�S��ec�r��SneI0������8�?t;�h��[J����[S<��<�������'��B]
���<�&h�����9`����,���/f���y@��|�D������{��I��{�c�Ul���[��Z+���E�oO������
��]�����Z�!��6�G.���U�^�.|Q�%o��x�7�+B�
���J�j�-�#;zr�9��Z#����<rt��
p��w�M�n����M?D���{��K��2�8g��d ��;��q!��N�+L*�Li2���h�rx��)l��!�����4^r��ds�-]�*{	�-| /�����=o�7�������6�u����t$����<j��F��q�0+�/ '����?�?!R��6P����R0������4m"�4���	�4�Y�\;U}����3���'�H[%�H~�i8���q}x|�_��gC�?��Nc�i���Q���Q�b6�4�I��q	3lQ�rj��sV����y���m���|Q)��;�Z�H��c�Z��?���#:�c���t%���N�7�eh��D��K�4;:H�BH������
��=��E��C�����&�d�4��;&�Q9\������[�f	$%�Z=2W%����%4~:�K�k�h��c�\j�����/��$�m����i�&Pd�R���p+�_�Co��Y����1e������u_�6��������7��%�.g��D���1LYh�{�E��F�9��9��EWc�D~�(L'�������e*O�K�B���-z�}�x0m��so,h�Q:�r�q������?��)�����Bqf��0�L����F�~7Px��������\��8�����L���W%T��xS�3IcY��@����w�|M_|K�T�������o�z�,������vf��B�?8m����82�~�h4��7�_�\�
����9����\��{�'4W���m����&���W�|0����������ZZ�����^���w
y�����/�a�y��d����IB�1�������"�Q��O�[�cl���GPY�����I���]�`�!��B����!���{�8�z��.��5�����O~�@�g�����io;�OX�����%��������Lo	����9�2�/_��k�%V\]����[���k�Lg�m^@���w��X�
s:@�S%o�M#[�C�y������=��a���q���W�*{X�������o8��6���Z("0~�A���A���~�)�st���=3�P���T�x�0e�I�3k������5gA��NB�(��"�`�����wy'���a��|`�$qD�Xg~^�d���j��1"�V���o/k��F!L�����W�'&$��N����"\J���� ����L�����db���Z ����hKW����U�z���������E�i'N���;7�_�hBN����C{����1U��:�*��<^����������cSr��������c�hv@k�Z��CK��F5���.\B���������c�������0D`=����s8��[��������s�j(;4�eP�Dv��'�n��?c,�$����
�bkD��{/��D��M��l��Hm��,�c�A-����az��&�*s�sb�lO����	���p�����p����i��z�@-%���� �
a��D+U���w��G�%:c�����Dg�1"��(M�C��#W�XO�v�����?�W(p���f�����$� �|���:h�A����O
�r������S@��+�q�RY�+~������LuM����$>F#o��!���u���|����6�~�@(�]q2��	��>&!��;\��Iw��R6��8������,#�������v'����M��kjI������TB����iE�ta ��w����\�Z�hV�w ��Z^����A��	:���dx(F�q���3��P�d)/�
�$��1�����W�e'���v���d�,2Q����W�`2�X:��O��m���j�B����|Z�,,����
`!�o�[�<Q�`�go���%���	�����r���9��!"��d7w]`��wu73g����dDR4f9E���w��w�����4m��m�8�j�-����E�*h�U�J���?��U�7�r��y}�>���b�}[���yN%�y��F�Oi�H�z���W	�dq�n�o"����V��J��P��y(� ���rh��~��!v�~���SK�������w�t��(�L��4	�i�w���w���)����I����k4}�&)��	GJ�i��z��LtX#}$��f5�z���d�an�x"yJ$��~�����D��$�	cucE����{��\{��������/i:�h������k��{�#�6�J'��u���5��>��Z�vu�.�V-�71�����G������C�:�]��*�".��S�pD-��C�-����qw1���l����t@X2����@�	}>H4_I8��9d���k��e��p���M���c�m� ��F��X��i�T����������*fw���-����F��)�R������S@5�b4�w�^�"����iD���f�'a�Ku�'���S�m
����������J�vZ����K�Au���0n�)Q��q���
\j�����F<�}�������"=������l�\�s����6>NY}���q��xA���wLr�#L�H��x��Z�}��'�.x6:U������'�~�b��lE����o������$iZ�KQ&��rb�s��eM�Q�')�:�r�����.�?
�e�C�E����0	P��N�I�����P
�
��'9s�c�����@����!9������;�&X�	e��>��������E]*�������Ew�-w B�l����~�j�>k���x�3��/��A���wtj�����w;�M����^����]Uj�����4��0'1T\��s��z$��p'`w��AiN�f9=a��c����A�A�G�(�S�(ze�I��\���f�{.aB��X�d�~���@����u��e*jU}�5�V�[����� �3�nN�<�Y�{#C�5��W�'@N�Mw����vdX���-}�nv�nr�r�Tp�"T��K���dY���j'����LX�F�v��K���@
V<�3����q�g���]����gz`��Z5�r�
����>���_��/���$I��sI.���9���9�e����������$���:����i_�.f�b<�Rp���X�����X0��Xr
�-s�ZN>�a�����@��T������������������~2�"Sn������0�9�Q�47AL]��P�%����Yo�)�������j�
tl�/��^Gu���q�X����������+I���}q����CC�fs8�p�j4�YK�y;l-�#N����O���X0��/���P��3LX��8$ lB����X�������y����}N���QD2(�8��D�J�a�����;���xVn\�b"�����A�z����b,1W��f)���ho$��@m�F����Ep~�8�b�-�S��=�A��3�\,@�eFG�ay���h��8�d�JP�5n�q��RnH6G6d*�+�([���D����U�x5-���LL�=��U(-��-3���I������$mA��?Az@a��7�}��^��c6AB�d%7x��y���|���O�r�a�
{��r���}���w�;Za�{E�#���u���zb_��
��F����\�x�,j�r]�v�{X��>?���~g�"�K(c�A�/BF�vrC��}����|28!�
�O{y� ������u�q����Qtn�X�H�ZUY�����e�G^�{
����E4��B1�?���Z+S'����K��k+���i�������{�iB�9:�CWn4�&
�����
2��0�viYW���Q���"������|���sd�a-�������l��������HL�+>FB�\[b3���{��'��������DC�]$�
(G��@=�����������o�o,84�%
��	���GZd���m�W����nW��Jo�C
w���:QY�Z��{"���~�T{u�pI��'������0�;������L*����}S��$�ZF�nL�����5�?]�D��5��'�j����w2���"_cZ��W����w�]m��S&M�wB6PJK�[����1�����xk��:������wq��:��������]M_�����b8��^�/���a�.�F��6�`�o������V�y��-�s��=2^����d��vR�W	KX���e�
v��%� 0B2z�MP�+i���c����TJ�A��n�a7��8��gP_��}��E��5Gc�H�=���>��~��2��5�V�����A��"�l]%�8Q�o��J�G���:(��_(s�\��{���V~�Wa��}-�N��*�cMe�L�5�g�L�eS_b%������a..��������5pA��Ia�_�++���7�����{��:B|d��+�����������g�K�a:>{��f}y��U�3���r>7�T.~����f��\�0[��N��z��?/Ei���#q_�~j���d���[�,���>tQ���)�-yVe�C_}��B�G#���j��c���VwAy8����>�e�b{��'�>R<p��m���UL��$e�W@Cp��^L�� `�.	�"����s��o�v����z��V���<��>�]�����p|��bG%�Kz}M��p�tUb�g��\��[������e�4F2o����jOx����v7_apy�;[`e(5$�$�Ck��7hO>h9o�*L9��������.�&�����;�p�R���Yb�U������U�h�q��I���j�67��y(;f3�yW/�,./��#B���3c1��i�;(TS�V���
W��+��lx��e`��	k9��ziN�w������^����u�'�N�:.7��~��#�=�r0����[v{v��!������T��tZS��%�[\���Q�<��
����-�#�����
�����b>���*fx�w�s��&�f���Lg�-R���X�Y��m�8��	�T����o�r��dc��j� &
�M�w�G�
�\��qS������J�r����+�9�����[�t�k?lb4��!3wU�;��M'����o�IJ&]Ot��7C��v���
����-�H[���LppBa`<�=i���j���%m�n��F2o�R|�����T9������l���x�l��aE�������'�}������C�YL����M�U
Lw�l9�3�(Y�����h�I��wO2�rrY��^'�w�7�&��'(�I������9��1�������P��$f��oJ�4mAQ*w��)~|U0M����-XeYn��s����N�m�$�>�/�&��&������N�p�}O�������=A���"�����\>�z�7�0�N�W��,�����������;�Kw5a8 �O���B�����{g�����wZ��Fu(@[%6����q
��|�V���W�"�����hc�g��M�d��D�fQ�[��\o��J�Ti�q?U����W��,[B}�nG�|s�y���Gg��a�C�	���3��(��.?��T�7����]�Q�n
�'~�1	D��+��1�������k�wo�f���]�0�{���/8V����v��6��F�;#����q�a/�|����i#{���#!!��E$��I��P#z|}2|����-u�����J�Z�<������^t^��L��o�xf����!k��]=��	��lI)�#�<_#������^]����\�t2j AF]������w�Ij�n��[��X�v�w��o>z����X���w�N�����z��D������������
	�;��9�Q��4�K�=�g�q�K�(:<pd�j�|~��C�G���������z�����M6},����&��p�x����z�8��)��\r�b"������dk���+�rr�����k�s�]�p����r`pJ��\��X�s��^���A�!�R�bqfst$����e=����QqN��r��=���������7��UO2x3��1����1h
:��|��+_*]��E�\����c�'}	��=��I@��=��%f����t`��S���L���.Z�8�'����:uLx�F0/���:�t�!Q*�HOe�S��]?-j��X���I�Y��!�K�~�Q��^��������+���7�n���,S��b�X5�A� �jpu���������p��'�Z�
�bN���Y��!D����4�Q|���>B\{|	�Ak:��6����F���*#w�*1�����Qc�P���"��:h�v� &�8��{�0��x6�����M��l�x<���F�Y�%q���GnF��9�{x�V��
!�����r�H��X��n`[��EFzd>� ZSa&�ku~�����|�|�x��]��n������\+��^��NE��\��b�~6�*&j�;0���Mv�����(����:�]����H�C�y�so�������V�%6����U�@���
rkJ�$���0���{�/w��G���?j�V�Q��M4���+�$h�@�/.e�����d�����mP2���;-��{/!��( 0]�V�����/'p ����1��T'��g?�@}����l?������N����S�P�)��aA���@�IE��B��DYz�5�e�4M��&�r�d��|Q.�,Y�&�����CO�=��z�G���\]YY.v���r���$-���#�A
SR�;��9')�$�@��{�F�����l
#��U���VvR�#��F�f�D�1I�"J�wJ�+!O2�1��T�(�j)�j��f������
L��0|2on���`�E�Ks��x8��#�?���2��C�I���M��oU����}��+�(�'�v)�QU�Y�;��J�3I1��+	~��Xz�;�����YBE�8���e���d��`�F���!�
��f3��]�)I?G#�Q_�-b�U���-�Q��E"�-&�"z��D-^�Fs��{}��h��������������}����Dx����G;��5�p�y=��T�6��l�qW���1<E%��*����1��
��kW���0w���V��	x�6@���7'b����<g(�=����D��G1�$�/������
.�th7�t�d}-+�dc��gb���>`��3�P��K%3�c����}�4�h��>�����1fHJ�B~Us�2���.U�:�D��
f��������a��3�2Jc�"����[Rx��Jm��5��F�OJni�*����^�C:�'����a�=�9��t�(	9*�c�pF�i%�������E��Es����
������J�HH��9d�x3�o���B��1f�e���~8�"�t0$��iD�1MS^)��t�dG%���i��
��^��T	�����o&g��/j#LE:�L ��2��#]�������fWbG���!�P0����	uZ��ZW���C����~)�N��][w�;�P#���{�n�����[}z�x�����~�f��)a���Q[]\� X��;XM.��y�^(��T��Z�0��n���1��I���SJ��	����e�+���3`��3dKh=�S��X�-����e���s��N���V�9�.��s�aZ�?~���Gv�O�Vj��:��90y=���[��W����]��f)����gD�]��k�MJ��y��w�O��<
�����B�']4{I\��+�6��X��
/F�q�������&.w��9�[u|�{tr�~�?�Na��^������g;*G��j�����,=c�)����k���y�H����������O
�
z���/w_��~�,5����nD���R����q�����������.�8my��!/����,LZ�.��C�=�?��2_�$�0��Bc���tr�u�P�'�� �f���J��d<a? mYL�TU#`����hEwq�rf5c������x8O��^��&h�����9��)L��y����[�J�KB�#���Kk�l4���O�����1��eQ#�����d�&��y�M��g
[gBR<Z���+�
�^�	?:�YJ�%0C����(P ����8
�A����cg��u��%E���y���6��n?���;%���tM�D_�<@���	��3��-�h���<�xVJh��3Z�3�UF��������RUO)�'��'����"SR�!��Z,�,�7��p "gJ���P�^WA���������b/�Gc��'e�9)����4�y�9`G������=�j4�����Y��>�Tp�=��%WD+C!2��jY�~������s��!����*��s&��/��l���Q��t������X@��%�F����8����n��/�h�LhG��������$�(������Dm�8�XN�M:�f7M���X�V����]���p<�����e'��'��{�3N{�=	��h���
��b���#)}JM�0iQ�X�����7�
J��j�t'9*���4�H�J����>�<�9�In:%Or��I�h`i�4^6^�i�A���D��IUx��������	E+�U��w�GE+���{�E���j2.9_a*\���I�|�ju���_5w���3���q��Jo/0�E��b��ncz�i��I]��U����<�D���L�����&�7B��`^@8_����3qPK�j��F�����)��=Q
�i�B���w��iv��r���l~#��"v����X�b[2 �j�\�@���%�>Z�]����T��^+=�y|����^�`� )�H�=�E'�-��1�I�K���� b^*�;�~�y|������SR��(��/h������Z]���l�<����y&��=�b*�$P/1����t�������m���Eo�?���s�����'��`=�<��%��������|p�����-�����VD�������l��ey,���D����f��������66�� J���DKSa&��.�j���o@:��M2���>���q�L�-��91�����:n�@�_�kg:���?��m�yoF�D��i���i�.�kU��s�O�+�4��!V�7�7qs��Z#:��0���C��[��F��k<|oVk3���}�s���&�o�c�a�pl��3�k�~�53c�P�����`!c���.�$w	��DQ4����W�d�:xH���gc��r8�a������ft�b�4�`��xd�q��[���+4A�M
��}��U	{�>��������|��ir�"������J�������8��>3�����������Pc���O��0�����@�L�}	������t�ik�L/�!d��1�H�e�I��:&t�0&D:���z��`���	���E��N-�F�&Fj�M��%�Y���xu��~ 2��h��/���R����6Du���������~���zzm6Y��I�@#C�y��!fX��0���C���X�e8�	2k�����z=M��#7��,a��x'N���w@����>�������o0�\Z���uW��B�.jF�] b�V�1��NA7t����U$PH��|�������:��������AW�`��B���8{*��2�����D�KK,���B�B����w�fj���?/+����z~�����:���`�<��xD�@���,�#L�J��]���
����ez�TjZ��f���q��0#F���eD&��(����{�6��0%��to���:�2s"3���,HP�^�=��NM���xb��$7���I�5�����hY��r!r���yo�|�hv�!����F|2�"���_��=�p ��l0,��K��	u�(_4���|�s����z�8��s�z�Om�)�C�.K�*�VE�/�*�Q��u����K�jca]�E3*�O�O��8��1��4��2���[�(�v�����[}=�D�b.����iO�/7�sU ��&�9�����
��H8-�om(f)������ra��5��f����iT������10m\�� ]�!]��������=�.eh�S=�wkmJ(�+M�"���8(������w/���E&��tc#���4��Vde1�"��,�	|?�9�6����`��b��@��O4�)R,dl!����8P�a�-��H��Ck�(�%/��A<m�8�vSd����jh�n�������g��1��r�E�A���^�z�3�B	M�������"e��Byv������v��T����������{��
��n�sT���������������q���c���������{�3h��z��m���9j4���	���[Q��[�
F2�cRg3bQ8.��3��z�x����Is����]M�<�Fa���xCb�	�SNUu��N��n���_��Z���T�y%�d��/S4�����kao�Lr��[|�2O���'u��J��.�c�S�0�����!d������gZv�Y�Q}Y��L��/����m
+�DM�\�XQ
�p�q.��J
����$6�;����T��b���_�k�u8,>9�ld��T�u��N�zq!��i���F(�B��a> ������'���)
s�����Ds��u���������q$��O�.,
Q�X������O�hc���!�!1�m�S����Trxz�&\�S�I6���/Z[5�I�M����%l�����A�)6�r;������jM-/�
k����~����4�3v�B_��Z���u��z��H���i����IZ%�a��]r�!��M���C��V���M�����tj�������%�5���,C�ZS<R!�2�Z@�6�PwW��
������I�,LPz����S�g�{z9��������)`��vM���p�I��.1�[xU���m��\3�$�1$�`u"��m����=�'.vhu����'D��y}U
�*�j���&���7��]�e�I����:�=Pw4���e�O��5M{ghf���Y�&��K���"t{m�^��8����l��_�t0��3��<�D��]�]Ta�qLI�@�|q������~�v�u�o����:�B�w����E���K����^L�7�����_���q�>�/�J����tQI\Tr7���	2���=�?BD?'. ����z@��H-_��"X�@�1�P���Y���`���"X)�j1lr
�����c����i��h{��d�
��!<��e�fV!^�;�������%�����s��F�`��} .���>��X(q
��]Y,�5f�:/�b�ndMU����V��>���Z)L~-�'�0��p��CD��-?A��C���[i�x��JVG���?8���;<8>�:,�i��o�N8�S���_6�{���R�Ixgj�����:98�RA�==�[H�~a���pT�7��f���Ce7~G� ��CJ�$�8���Dnd��|�X�����#Y��������w�����Y�:���/�R6X�$�M�6�w������.�;����STS��b�r�2��E���������"�Vnzt�t�|�3�����(���e<2.Es���j�6��3e�@L~i�5
Y}/?/Q�,Cu�55���PD���R�U�(�4�(;��T� ~���;b���7�>�-+1n����������S����BS�mX���Pl�������\��S�E�R���q���VWYB+�C�IM2��J�*$�g��5q�������]��~�J9p��*�5p�T����Q��]��}���D2N|���>:S�t&��d���;��S�F�����x�����������������t��}�8H', ��sa���\xJ�,�r��{����i���mHG*4B����v%,SlF�o;���dN�Kv�q.90�6Y�#�yik������T�����Iz��Ii�O+&1�S����g������'G	���'���t����:|���t�;�t�����
 �,�,�15CesXP��"8�`�w��&��l��:����/�S���i�=add��o=(3d�����{��P���m���f�aa����3'�{A�Aq�k`z���~�V9`DZ����9x�x���\�zh��	<�
��r���+�09w����c��z"s�qC�b]��-�0���sx<3k�Vx�[�~�c���f�q�y�����j�9K�?j`G���������O�������>%4�������yg�����)��+(Q�7���)�F0*�����z�h�U��q$�&#x��u�%�(3��\��\D�f�$�k�������6f�|�n}�����^.9��#d�|����O]&ky����XYa����r���Ow^-�=���2��Y�By,����2�s������i��~h�OHYt�����3O'���[)�T�&��w��F��r��S��q�g����X&X03}19��}��(k�?
�S��#�%���u'Y9o��%��B��DOJ�!�T���N�:r��k��bKtsY�N���$DBd��F,#,�}�S���
����~V�a3������}��4���~� 3=����Rc#�������qb�"V��X�=N5+��������	�i����{/�e��
~3 �jh���������/����u�;��I��3u���n���!�&��	�Q.X#���j��Z����xi�$8,��[<[�������������k�Xp�j��j�5��v8ek��<��e����
�G9j�`�������[����~��o6
3�qE�>i)�]ww���
�)b�����]H	���8ru�Ng�t�+����:	����E��?�	��d�=��x��T?Nd����9���o����wTJ��;���|���p��>��"�2�+Z�Cve���o���z�L}��D��<�\k
%]j����|�y�k���<6gGX��a����X���=(��aS��x���Lqf�����.!�37���u��4bs���i������3_{��|����M�l
�6�6��
?����5�jr��R5�^m������^��;Kf�%sC~�o���<r?�<�����5��@
��2�Dch�8IM�T�HM	rx�82�"��(#�tB}��J�._��w[�-je"��-�)h�F.w�<�2����hv��������f84��������������K�Cd.�8�����D���U�����szZ����UD��^����;_1�����[av��B���8�ro8y'f�-H�� *�Z����]n�fk�
��{9v)�}�B5������Sf����������I��{���/o�7�/��L���"�%B�'�?����)��Tp��EN��	��07}�GhDA�����9���g���A=�%7�-af��<����e���G�hFt�pA�v�'����@E�M"[ufGL�n��|��M#G��s�^���4�Ez���9x��Q��w��*V���RCx������l���.j[���d�������@-�N}��������idGs
]�v'��a���f'��%��9�5]�v����y��Y�����qo4q�<8�NnC�!
�@g(��9{�^��p.a��{�]���t�m#����b��b{��2��H[�`A�&s-������/(M�i"V\�aL�������1�����3�c��j����f�� ���B��������'���d��C�5�|���7V7��S���r^�%��(��kA����j�$=���d�9MX��U�7mo�yb������<\�X���`�qkp��iN>Xu�1�C�b1w�h���$^(V?�;we$���(y*�bt�q�U]�V����5=�z��x-bIU�1�(�����1���������3���u����77�-b;I�n'/����Y|�k��T#��>0�K�Y2_L����-T��A�]�z��f[�Ol�'�}B�KK;�}�3������tt�&q��^g������^���O@J�w+���=b�D�'�S�M�TJ[���RSlC��!%����vtJJ�j@"�(=����?9����y:D{Q��N5p�2�G�=m?��X�
�1�|2	-����,mu�Z��p=#��EO��x���0��Be�-�!8+��n]�
AA��;U�-�v�<��-�M9�ahuf�;�E�����1D�I�<����. �}"|�6�*!V���?���w��{�s���w������#���v$wCz�>|��I�l����X/������]c�m"�v�x�=�aS�)S��6��U�R�=dU��6�b1 �������h�;"%�	�M�!�](���,PF����7��&��XdW�#���4w�G(��5N����"�a�O��ew������lY&��`6���	b�����g���,��������w������u0����p>E5�M�Jh_���|a�S���'����������+�#��1Y1W9�Tz�����F��#)k���[d��{vr�Q�*i���`9v.;�p*����X�X���}�x�Akki6�������'"FZ������s���\@2������/�f��eN
�V#����C��B���p��\a&C��5�b4"]D�l���d��&d�\��� ��@9�2�P�hL�.�-��zD>��~m�9�� [K����x2��/�={b{s��O|$����������Hq2�������4�6 �R����������J`�Wj7���+�%�,C���I.���<l��
t�Y�������dn��'����>J�"66���/8����c�����-\����i��0���s��4.�p��R����}#`*���mJ�SD�)
�d�c���P����X��94�"��F�wQx���\ N�60�����W����.���X���R'(^L��O2�6�(;3$��Xt��L��a�n��g��f.�,�v����F:������_n���"Kyr���3�*�V��@��\7�	h�hg����t�s���n��91Z
��vKFU��'�g��1��
7��?9/�r��>���w��{�K3��_.������.?���>���M����'�������+�,[{�{3�H�aD����h�>�<c��F
6�@���fx\1mF��l�����/����d7�*���h��M�l��f"k2���L���>f���qgU��1� -���ZTIO��������&S�?_{
��<����Z�6���=����2�����>s;&� ���_?A$=������^J����k��[���C]%� B�GR�c�x;�W��)�x������H�D�M	��!3�Gx��7�[��>*�0�c���#X�j4�7 �G��k��?�P�1�y���	�u����BTl�)���R!�b�jv��v�"��3s�:�V�6q�b����0���O��?����7��]�B�;F���A�>�n�������N��[�U�����G�1O<>!�74�l&�k`��/�>���!c�j��R�+�������
v�J|��Q�$�9���*��xqFI�.�����N~c�
20����7�"�� ��G����Jer�D���UlM��N~�O�N�W�*�.`���u����3y!��y�5v��p�Z92r�t�#�����<�e�cI�h�
7M��&����#~��>�i��g��k[����*�@�}��$�����v�}smh��PM��I:�2@�B�b����&��xd�&���4��/����Jo�=�������9��^"!mh�o��[�6�H��wo���{,:�d��a�.�����G��A9�7�����@H��L]-��('�_��$�Q
���)���a��H&���lMD*���Sk]�Z�Z��u"�w.F�Y��i�!��	=Sg���T�h;]fv?�2����twD��po�9�`<{J��:�
���3�����q�����"�U#��D������]`�����Bb;P���W}��>���O���:]���x{��^�;���9��������rdw��b����/rw��N.1��!�p��t���������y'�L�����gZ����K�C������#���lFr���;���#��np��/_�&�A�*)�[*����PQ�x�O(�G�::�����Gn��QE>��C�# hX�'����A�"�($�j�4����Nv��	��2���/�]i��PIy����x�34�*�
h��0�Y�)���pY]�����O�$�2�.�YO/���Uk#/L�'�^G�r(��b"�!#��:d����]����mJ�939�@�v���xa=�c>���y�.��%+��+��LMn]�B�gB���@W���MV`��b#f��=��"���!������.)������U�_�9�se�6V(���>�v�	�>�^K�k3�u^pQ�P���K��������Hq����k�k��p�|Q�&U��+�
q+�3qNk�w�zdj�f����G����'�H"��U_Y���S=o!�h����,���c-�E���<��z03���M_�xh7�o%�������/�&�j���G�7��
�F��I*����b�-���O���f�34*�����F�R��kJ�
��<��������y4�H��Z� �jZ�a�2O� *#������f�>-��J��*�r@w\	�|'�����2_��;������gg�z��w�?��n|0Z�C��v��	�*V�T�����������������q����J����s6H��������I�����@L�A@m��Q����i�%j��~���j5����������C������5�1S�7{���1���K������9�x�O�'�
�����(]�
�(��6�/��r���+���+�����r���
������m���n�T���>0�-���2��2��e/���Iy���Y��
�����<�n�n~#��3�b.Q[�0��BL8��kh��M��gml���5�,�x���SG����s<TU������?��~�8R�~�Q�c����Xs�7���x%d�s>���S�(��&=�V������HU�yD��G���%T�E�8C�Q�*�!"��Q�/�A���F��Tr��nB��YH�����K,x��Zv�[�7&��_�P��r�F��C�(�y�\Bo�5C����I_)�������	�s$���O�Y� ��4��;wB�gx�a��G���}�{�<j����Q�Y�M���H�0����LJ��M����y�[�[�W���E�G�����/�h:#Q�~
u��erR�H��hg���:�2���n�N�K����o�$�S���a6�l����<��a������/Z�i�*�"�K�DC�Z�I��=}�a�h������",�a�����]�:@[��!��U�et:�N\���W�������y�H}=5]22b�_�����T���.��~�$K�D]��8���]Qfa����w��K���D:/��������5e����^3'�������N�u��c��0F�0�;�R	�Mh'�N�"\�]b�'vS�GO����9O>���l)��������AB��/'%�������+��d�B�V'&���cf������B �"��pf���6!4��6�'�>��R�����@�A���.s�5_���F�L��������N�58�������W��n�#�m/x��|nM�hRq�����z^��r2���j��p�b�M�p�����������p~��)���Yo�Z��q���H�{��^?���N����3��
��\�;���:EW�T1���non���~��ye����zw�ugyyY��&W�������R�Q����Z_UKk���m����f���3y"�a�[E���/��'Eb�f�1��7�t�7]�{g�x��������z=L'g���_/�������g�U���w�^�l��g������{��fQn���[�Rb}
���z�N�yn�kIW��H�j
:������Y�3��9(*V�UN/�����<����*��L�/t�	���Y���oP�����a�4Z������bv�d,����do�&�`.:"�����]�(K;FW��'���u�f�
��\�]�W:T0��@%����Vb�j��&�`������/+J���RL�s��RO��p|����R��Q
T���GoiE!u`�������Z!/ ��p�O���U������g���<��E�/���G��Y��Tk�L %���5,�&�0r����'�h<l�)�����C]�P/:�~����D��Rd*�n9�t���V�������/�d����G� N�<�\���	8�����'y��$+�#B����l\�+M���k�}Ol<����y}r\�2L"���L�G�4��u������f1�Cl���++�"�)���C��m�d��D�S��*�<�s����w�O�k���O����n��0yM��Gl1~F�)�����-;�l
 ���Y������p��hK��s�T�6VGa��M�B�~��7Y�s���['d8Q���u��x���zkS)�w�cK�x�&��X��pN�k�U�TV�V��Z�r!*�
�]Bk|���rP��L�C���u�������eXl��
~�������%��h��DM�Y��]��
f���:I��W�����./p^AL�0�w+G�1	.
P��GMaqY���_>���put�%/l�����z���������(���S�'���F���>)z���k��P�X������C~�RW��&C�= ����{��C�i���?5Tt��gh����h&��y�As��`^\�uufXo����;�N� G��.���b��V��vQs����Z�RA?r1G�~f�0y���T���jr[d`���>+������Z��Q���5s�x���y�r�vg�=KY=�{��X������[��	�$��w��--�[��mG���|�������@;�V��At�9��u������bsN�����#����O;�.pF���;���3l��������cW5�u��3x�������Eldd��p5{�z��u	��/���~�=�k<v�]4����#C��x'��L�n��������6
��k���jn��2�P\�������6�O+H�������I���[��)���y���o����{��
_vL9��[�H4y�t�0����g�y�r�@�Vrj�Nj�����.f�����{���Ybvg<��_����������g��P~~��k�s�a/}G�A^����
��f��ez���1��y��U����1�.����l�;������iI��j!���AY+�ss����������0L%gx� ��.B��

Ol>��LU+�DO{I�;#���ir��m����4�������5����oq�HN����r�,�P~qTT�
��2��i��c���y}=��l���q{������2�:�'omb�(a[xN����}`�Cp��u�<o=�&�X���v�mB��t�m"�rx�Q�Rb#U��6YL�>��p�v�d� <�=���7�1�8z�o`�O*����k��?'Go���������1�����<��?�����R@���������h�*�a�h���F�����F�'����c������]�����?_5vOG��loh:����i�������'�����d���
��
y��"��S�OF�u?���{yHkzv�����/yW�o�LZ�lGh��vX�ex����?�?N�
�b{�&�*���{����}��N'I��X"p�MN�$����*�H]u�~������vG�`7)�%���$e���d4jz�i�F@�������_�=�>��-]0�i�qv�.'��Y-����s���-��'����o��
R'���dr>tG�K���zF�;�'lh��7]�'t}��Q!>Y����.�z�T���������`~.��{��_�Oo^��9F�9�`C:j�
j�|���t���y��B2�Hq��n�'���E��`.k�A�U�im����_��U��0!�Wkn92�+XG�����a������T
��@$.?J���W_�(��6��^��5�7o�h���t���rb�g���ja�(:+�P_�^P�5	��u������y����� ����4/�'�������,]�"t������s��p.R��"��o��,���]aQmv���L0��I(��3�������p�"T4�@[������n���51��y�)��
�������:�j�����}a�s]�P���d6w{����N:u�g��Z�&D�$n�[���������!hB�\78V2����nx���#3��EJ6�Chd��W�0�����k����nu�!v�L7��L/Dc����4w�j�t�9�����h?�<�^w��!/��H0���c��#T�o��{�������@���jC{BO���]��������j�����o��-��U�\1��R�8���B|��-|�����?����c����q�!
�6Qx�B����d���/���[��j��T`C���N�����OY[-|^�t""��N'����<2o'��&e`��_��2kUz"���S�����q���W�"�Q����x�=�c@��opl�����1��/�l�Q�fvt�Om�?��C���A�^��G������/���������gS��Z����: e|�N�yDBK>�Y�����4?�l�4_,���e?���2����r�]j�a�v�
+��������E�.KIV�e���J#2;��6%������|Aq�H����u��C��d�������H5p��3dt�lM�=��
�m�[P>Q\^:G��}�/{���e+*�)���B��e(�B����X3
��X'[Q�������w�
����>�G��z��Y�U������--)���}��
,�]\�Gr�<���&��W�!�*2L������j����B�� ����M��������.��=�w^�1z�9��@@ ��2����g07]�.;�iP���;�G���K\a�-��������==����>5H���,��ay<��e����������OWTo�L��v���w\�yG���2)]2B`O�#����q�:�
����$����{j$M������phd$z7�J��������6����^��I=�cA=N����������J�s�+����mo����HFq\��7��.@2,:��L>z�k����������s�F_��k8�#O�����u_(KuHDR����R&CE9z���@�.(����NG����(��j���
��������&���}�����mY6T��5��c���<=�4�������G�y�B
�����R�!�����&`���:9�nw�$�R�����G�9��oT�nW�79z���IWbW��4�
�i���H�1�m����Gv��%[�y�,�:�h�,g���W�����S���f�#/��YS����{P+�������pQ'�f�:EW4%���P��b����<�cD�&���nR�&�)a��K@^��������#�UDv0�"=�)]�4����������xe������F�wU��*Phl�}����6�����)���>hK����A���A�%]_�Z�I�*q��b��~�
F�������5���_>���+��DJ��l�=�u��Oq�r?��Y�Q�}�Q}������3�����������������e���+@�t���������o�z�������~z��m�m���o���}���7o������z[�����������C.�/�3c��o���]Po'oo�oO��v�5�zr������;����w������%��J�����'��������~�?��~~���������m�:���e������	Lx^��G"�q"n�����WC�)S�n��D��L������?G�}t���l�����DQ���8��WN0����w�N�>	����l�J�z��W�4?{�����9�g�V!_�%�����ZVk���9�j�����^94���Cx4����Z��SN��\%2k��93���\���?�]��m�"oB����J�"���
�c$��^��<��
�N/���������/I��/K����
�E�upZj�I�S��N�h��X���_IU�^R����O[�5��tI��_
��T��� ,���O�x���\K~�o���>�iu5zh�c�o�-z2��\�K�G�k?�H<q����O��<��hd~�i�"tg���B������Bm�����������o���<��F��<�������k��r�o���%��_���4i���v�������v�����
b�
n��8�����Mb�Mn��U������I�N�����`���&���t�)z�B��~�n�#����{�l�lh���
����%[u���dGiZ�� ��R�_&��gw�w%�i���;M��"�icO��/���qff�(rW�������I��uC<��SZ���<s�O~���[btS���������w��8��R��Eo�a�`�Z��D+(���aB��������Lc
<w���0���$��b����q.������t�&
�.b���Q"�y��k�<��5.��N�|p��S�������-'��%����hO���������)E��������kh����s��V�Bx��>����p��O�����]�o���X
8������]��n�C�T�����eg������`��]pr��?$c�6�{�^N��Ei��te�6���(����0�A��@~8&cc�a��x��i�?:o��	)�%z`�*O��������Z��G��J�z�2�K�>��2����P�m�2R�ca��fKI�����G]�iJY������-g�=7O'N9�+l������6gU<���S�9[3���w�9��� ![��X����|Kw/uX�w���I��P��+l�
Z�5����V�6P�����*����1w�
gP�U���7U�!����@�����J�l]�+=��2��.���V�	P
 ��J�����2�p��u����]='g]_|�>Wt�]1�1�����K�O��x<�^?@e}�cQ�w��s�H-���V���[�U��\�0���hoO������w+�����������~��������u�%U��u,��5��	K��!��6&�}����9�0��
!�Ev.F^cYM�m�G	Pa��E��2D8����3wj��Z�)��t6dI��Q�i��m#'���s�����B�/��iof��3*��XOX���D����&�r�A��"%Q���.����@���A���
�1Q��[���6	-S'�%�<�o�zR��8ct	�X�9�"��6V����G?�4�R�z�-\_�$�gdN�V��Z��"i���E
���2���g Z}�O>��!�,9�8ka������K�2W.�����*�(�N�7�i�~x'����E9T�1�@E�����9C:��f��W��7f!\�>�@V5��r$5��P+5>9=gcXB7�'�$X���L���w3}o�2�0$�����Wq2�P�
�����s�A�ZX����:��U��i<,#����������+���LnMf�d_O�a���mA'u_��c�w����rL���#��"{�g��9�/<��������}�����u2��.-�8�2Oht��������E��>*�l�C�@�8���,���;�|��J�a�6�tY��1�HD���<�L�\���`?�?��!�y�|��g����������o\n�|�x�[N��lu(^R�w�F�N���F�N#/g�NC+hu��]v{g=���*��I<n���F2ziEz���*��~h����oN��s��O��1�e �*�����������7@�J�ai�l�������p�q��)t9���������3�A���=����#��-u��W����0�S.@�pn2���a?R�v�����W���^�)��5q�Y�QJ����h�����		>�����4��������E��n[��+Yy��m�q	x��n��^K2J�X��a�i��j#�����ps0�!��M�������w�f����E��v�X]WUX���1PMw�8\:��	�h^�����*#L����Pv�p���~\]���<�/��G�@��o]���S� U��U-i�{�N��vLxC��{����O/�0"lIC�+���,��i�������O�8A�������1���
=|��U"�#C`{�{�b��X%!A�#�@���Z^f��S�-Zmx (8����9�� 'c|4�
�[�8�B��%�	�c"�x�k���"���]bpN�=?v��Bd-��m�Z�!1����5~������|n|@�:������%0���H�)iZAu����i��a6`{�7��5�h�$)vyw;�����������++[��odc�2�N�6_��%B�>Gby-��9 ��E"�71���j�
#QWx������GH/).2��	<KS�L
V�	^r�vV:�s�O�+�t�������v}�b���x����I����p������������#��H�x�>-P74]���O?���|����*��_����O>/���}o�pDl�Q�5���G���_d�jD}� ������M�'���m�{Z�zco�I�o�[<���w���!H�=��?�����,5-��1P�zh:L��
����~B�^b��^�V�������=H���({W���n����(R0K����1���9���,���$MtR9Z�9Uk+��d����C����������q�}B7�7�/��>$'�EO}�����0���g�l�yS.�q�]�KM��F�A��E��b_�!�P33���O��7�	�YDe���_����J���N�K��!��k���$i������k[���uyyy�(������n�������|���	��&���*�p$�X��N7k��^�)��1�rB�LG:�	Bk��(��/��i��=tr�'i!'�&�^��Q����o�������v�Jx�@v�Q�6u	4��
�t�M{�~�7�����C�@������
H���������w�? �9Y[@������~_-������^�]��t���������=���{���vGz��A��Qb�&;��%-�����~r��w�d�����*L��l�bB��6z^G����L��Zv�V�kw�k�9A������F��R�YJ�+��2a�-A|Dws����2q���"<�������ZZ�\[��o�9��>@�b��	:�s�T���"����	T�k!�o��z��q�zFC�:Ig*���A)���,BM����������A�BK�=����������G~��;�gwKj+J����EL���"��O	�W�n������H�X��&}�o�[|���N��w��G(�!i�1��N���Zs�j���������l����:5Z�t~�k�gE�!\�Jk|�����|��n���-�������t�BI���������7O�������0W6����wo������kZ?UN��9<�7�#t~%l��"T9L����Y�q^NX:-8��d��dE�g}i-���}!��6���]�{���#��b1�#�Q��L�R����ym�G�p��ro�g9���Fln2����o���^��*X���X(���>��!��������C[����x(���x7{6<���xhku#�Cy�Cz��/z�Nxhk}-�C���
���:��,��pS�^x�_�=\#<�����C9����C��3���U����C<��AQ<�������+]�4�%��.��(jk�Y��!�����*(
�r�(���,��M�{�(��q���I(j{����r�����`.�',�o����p����#o�,�D�����������q��!�@�$�j��1@�o�xH��;�$�>��2U	
��*%n1#5����;�l��2JR�8�I�D�����8:�������ts����w��a�w{
��������G���W���[5�%~��,�o""��{�[�3���~�U!���*���PUt�	&�5�}����,��Q��\j��W����De�W�-m���CdQjG
�-y�P��w���&�w��u��"�,����:6z�b���eYN��x�>2������[T?����@�����w���"^��^��Y�jx�7vaM.x�����������6�1OCY��p:������CC�%��)�g�b��3_�[F`�Vj�N&��'u���$�!S���	�y[!G�%���&b��i�=�ca�R�W�-��}��|��LW�����9|����r��S�!����
t��
5�Q���x���h9z����Kk����5����w���9�8�Fu���G�(�@s"�������7�,J"�Qv$j�pb��.�L�������+��[�=�[���5N0���u�g�`�av���!b��%�H��P�noVY��f���e��=���9.5�z6�0X��(Ui�5%����IBfqc�O=E�8`}�'9Mdd�Vx�'6��i������xw�i�>�����y��F3~A&e{������Z�^���FL�
����Ad���e��5���a)\������{�xbt����BG
m~��U��p|MV�8n�eH]T�w�g��=�����I*�D���g�������t�+�L?��U���/]A����jQs����O������o��l����0{C	�1�?�[�\8�����(5\��l����D�x�>$�[���P���=;��}�p���B������B�Zo������RnAG����7��w����Q�����
��76���"A4KqDCwlw���W�oc�� r���Zh����\*s?k���t1���J�����]�lW�r7���E�A�F?:�������d�k_N����,m���
b.���>h=\_Y���6Z��1�5]Y��Jd��A���5�%"����~��������9�@{�6;��j�*�_����[� ?#���"��8E�3@�?&nJ�~��
8�"2�2����9��?`~��zp������k����`��"�h�3��S�ku{�~��Sov���Jq��a�L�;H���:�ua��>E�����R����?�Q�&������gGU)���
�N,�?���|L:UU3;�������i�8@�v�)���d�o�YJ��'3�<u�0�m��]gF��7�k��`�sW�}*r�#�3 0EtyF�����Z��{�O�W���u��>�Z��j�WV���o���K]_�����#���������%�Il��	�9���mp:T�7
��u#���d�b����q�"�L(�Z5����]��y���&.B�85���s�����+��^��6�2��(%����,��u�M�q�j�3�?�G7si���C��T���G�����M���$�)�����'����V���Gj�����j�&B������#�^z��'8?�$&~R$�d��s4lr�!��
MR'����qr����#������A������V���
�F�O�e��~��WVj+��ee�s��%bI����>������U�n��5�{�d��9=Gor���cU/=�m/p����YI�!��M�����^�����{�'����d^��#4�����W�NZ�����z'�������L/x]/������s[��K�>
��_9���t���l��v�.���FtX�kd����x!�h�YH-Q{�#�e�\��P�a�&�e��h�| �/�x��_A�����`��6��?��������o��f��� ����Mj��B>���gIG���(�V-
(�(F+E;;���pl1��/"Dd�������>{���d�&�E�JE=��by�s���k�C������������A� {9���:�:��j$o��=���O4h���������I�Y�����'��$K�9#�ez$��t��y �E7����[��Wq��S�
�/s��Ewk�l���{��I��F�2���l�����7'����E�?`.%l�K��u�<����������>���P�@Os�5G����Pt�KK�����^4�9B0�m��G��������?��x�tO@��T�������i��L�Xl��_(�Gt"��"�r��tU~��	�w�r���o��~�������Q��b/���g5�(�~:BC+Y�����D�W����E ������%:A��7O��s6D[y�T�"R�����������Z�!��bz��:
_}�C�������1[!�p��F{������H��7��0��J;9o]�$��S������E�C�/�[�9WU��G�v�y��D�m>m|������F��M�����Fq������&��p���W�3;J�>������7w��vo0��v3�t�����������e�B9�l�`���S8��z�%{GY�L�c��}c�����%����3u/m�t��i$�ybL�+��'���[	�1w3C`
?')*�IC�o�k[[�j������F��R��b��GI��N�'���}��G�w�j�> ��5B�;���)�4`a����4^~���N��@��J����"��I�JP#�#HEth���Q#o�,M��2od����Q��T`Z�_^RK�������xeN���q���������[�%Hr{�t��$?�Z���9��boH�!��WP
�t�,�������e�����l@�mqY(��~=>=�'��ua��Rg��`�BT��T������Z�@*[afT���EO��n��l��t�G��[��D�I�Ih-[\
��,���� �e��c6Hs7�,�����7�88gw��5��l?E��qv��N����� Bgu���������0b�(�g��$�`�v��W�����Q����`��zl�a�������&Yv=\]{����k��}����4X3:f�2�+Q�����_5�.�-�4�m���A�"Dj����H]�x�
�*���8������j.?�D�&��H��$�l��M�H$'��g/?Wm��~�V�dEa�df8C�T�\��km���A^���G/8n}�_�6*��p��y��\�k�����(�������$ ����.|�������Gh�w�����z�(�"�}b����X�~���1&Gu�����pr^���	��Gj�L$S�[�M��5��j�2[�5�5�1�.��}J�	�X�F|z�v�]uc�j���7�Z�F9�VL6�U,8;'>�6��?zW"�*
�����^����vO79
x���1�h~l�<�G_�������)�S_�x���u�h��8of�kQ<���7iR�tZ����O�>����1��>%�<.F�k���=� ��h���6����6�j��D��1���L��������q
k�>���_�&����a������
^�>�G�|=��K�7���[��E�=GiF�� �V���$�+N��.� `���6���y�c�C][���o���ok�h����p�d�iN����E��CY�-h?�����?MR������&T�����j������X����W�qu�(y��/^��[]ON�n�rO{�����q1���@6Sni]yk�o�]������q1������M	��V���5E���6M�
�4t���b�)��G���t�t���,9c��R��2�|��*2�p�/�_&y�7�s�������?���Cy�A�AU
�z���3����']4�J\(������j.�����c�h:��{��A�WS+�+�#���M����X�G���pj���=�p��3\W�[����-����
04��=Bx���:�������M��e~f��QF�W�X��Q���W�Do��J�nln�����coZL�Pp�������+yf��^w����g��/x���v"��w;��e58�"�$���S��:gV�&�|��h�����hi=W�#?�.S
!�k�}�U��
�q-@p�����%.��"�R����S�����l�G�7��4Z����
�[��������vV%w��I�$�1:�T�����Ym��,M� fzt��Y"�������-z��{���G���l����k�����7W7����@1�'�_�{W|�V���P�
3�
#����SW�H7��J���n��f�|�t��`#��L��ko�����G�^�{��KWt�)�c�o�2�t��:��"�0��!��dF\�����g<��a8����Vg�C��P%���R�/F~� �5P���)o[�2s�U-�P������J�����������G�Mmk����Xu��Ob�9��B��g�����9���E��(�s�/�S�@�e�BC�Z�����Qz����70R/�?��Kj�q_wi��=�,�:��3?�}�*�,�����z
M��r��Q3�E{S0.��Kq��������S�Sr�&_��?���>����	JVX�>�����q��S=�����C�3� �!�n�V��| ����-��{�y�n�9x��N�	��B:���Z��}�p�%X�\V�g�����R��E�.7��������#3~Z�J�\7(�R�#�k������I:�s�l���[y��z_��t�PT��8���^�Ur�JU��$���c��J�"�W��{\�c�H��@1���#����P>���2�85��4#�s�7ph�:�!|L�����p=��=F�>:x}��.�9��������F��J
�^�L�����������a)���<%ng��Q7���R��@��2Q�'��l��d��Q�9e�*@�����_;<z�8j<k7N�����+]]��o���������e����_~����n�j=�}(�d��]�.��q=���U�1+����J�t���$q���!�
1G�Y~����|C�?����NC����D�����*�z ��7��������zH,��P���1��]�H}�)(|��z�������wp{h{h��%����f�����m_��[-��b]���Hmf����]��@�wv�?! 	B4�:7��k�������[Z���
d]0�|4?M| �	�9�/d4rv���s�
o_���(���3�y����D�5�8���`���lXP��8���z��ij�Ezx�����s�bz�O�	B�2�4,���������
+K���J��[b$/6�
w�s��n\]�_B����!%�Mzp	&����dN	j��&����WVV�6��[�e���5r�Q`J0tI5�����W�A��i{�OO)�$�����!�~>�d��}��?S1����w��qb��)��d�?�X��8����p@&�n���.�
L}x��p�9��"������By
�Z}����{�Wn?f������u���7gF�kt�6�}5���� ml<�4H����j��u����f��|jx�r'v�C�^�s�3�r)���A�!g��v?���l3�Q��f8vw+��F6#�7	��T���>��,+���������'����������������G���c86�X�JL�����������Ip�Wc�lc��#/m�}=q�7]?����'"���������j�$�V���*��'�m-�"-�	3��d���a������+�w2�E�~�}����������yf����6~��Qh(�3q��JN
��U_w�!�uw�j�4L����M�A�7�NF=y��_������~@����:��71_�x�����/1'���������n|�����G��T���P������A�F8D���p�<�a��� �"�p��S��#n}��ru��"B����0G|��6Qg����Hu�����@U�����9��I0�����Ho�����8�[���ca�brg)������e�y�4���+\�R�*^��/wOp�~[�u�t��������� ���
��P~�]��!+Q�S���b�^:h
����t!�xz���XE1����{<L��#%	0��M�'�l�P�����%w��&�����I�P��qr�5u��;n���l�g��������?����=P�{����������	`s}�Owk�]��YA�_��Wo��K�W���P������������9"���������S�����[��q�^��8j���7�cw��+��u��4�l�7���L�(��J=4�I���i�����;^$�s��d������t���M��4:�����l�m�A��a`6�q1�E"	�P'M<
��y�Bh��%�]��O.��B!�,E�XD�]
��x\lw�[k�1x�������Ci����S�>���>�,�'$;��nK�~E/N~��%Q�[a)���\���.[�x�
�����������a�w�f�,�<`�����'
w����'�;j�E�f,N��\T����QM0��)�#�A
�dD����� �0;��(r.��+}��q^�	n����*.#��9�����dD���o	T��Y'��I\8�����O~��������*1������Y���k|:��_Z�Kz1�r����R��?.�t����>9O�bd��A��0���iL
/���L>N��N����pz������r������i�U��<��W�2��R�r�g��������^���
>.c���j|D�,
~����z����O ����Kt8<A]s��z�+���x�g5�`�#O����pqaF8)����^��h�������SG�����lU/H�(*%(��4�����E��7~������%Z\����g���������I�"<�Z���Ox����9y`s5/[��7��5��)�=0�6y=wd���S���#�`����7��?~��x�h���A����v��F2�ff�W�G���w�pNr`@�_M�b8N�����@�7I.x���(���v����#]�L���1 ?;N`�q?:[� 7�u�����8���qA�{�o������]p��z��xV� ���d2��4���/{���C=�e�����9(B�GP���`�7^�<�n|�W�WO�m<�4�Er�N��O�c�d���{�1��0�`�������k��a{K@Sk���'���W���9�������!&�a��5�n:�����)��2��A��d�RdVB:�tU�g�������[����7�9�*�����e7����������5X�/L��j���nnn?�j��<x��\oofY��Y�fjUz���&<�_�o���"@����6�����'vv�@vY�7��t��4���X��=��J������C�f.������� {�I�4��3��/�Mt7��7�V��7N�/�"�g���)�l�
��4���[����v�mj���Q{(�mB�=�G�Y�}[���J�`�F�"`�����.��
����G����>4�]��ap����u{iG��u�
Btj<4H�CX@)1MA�RCc�V��V���J�t{#iGR�Q��u-JN��Mf#K���at��s�����i�g��=9�Q�[���tb��
�.0����-�w��B"	4��][��C����ROujR���a��s1 x�Y.�f���*:�-�J����\u���������?���.�������(�
]if����*����'�
�7��23�K��3�������/z�',l��tt�K'�L��*�RyIT���0yY1:uki���J:��WV������n)���S�V��d����U�RK����`VMj6� �w�����3IB7`C�-C]���]�F��"Zi��&~m�V:T�G%(���g��z����|�CM��Y���2���)����v*:O�<nLm?�J=�D:z?�
�W��%�R�V���J9L����?my�������.������lKws�&�$�����1��l	�0�I����f$��-��1${�r�
���i4��������.����U@��h�E�n�-=��"	�a��j���sJ�������y��%��lw����]�7�����N�$��/�����NB�����j�"~kD��z��y�`�>b�e��y����xcdx���I�	�|�DOKH��-;j*�s�Xm�ypD\�5����L������^��"�OM}���V�8�9�k�`��������5V'���\0]���]��v������A���\J��K��=��gWW�5�V�!h�'	�@���-Y���@���at=�QE��Q�c��n�kZ]�d�����
=����,�"���&6�x�����$6v��O���6lk�oDFVHu�i�qw$��M�f_��0�)!>��H���Z]L�7�F��q��i��$���w��g[�.����/�U*�����P�Q7����x����0B���2���[l���1Be���JH�GP����v�f������*��b.UDd���8��R�����_�
������;��s�`��`b����(�kg0�4�\���}��aL�Z����r���SUR��<����uJ�����WJS��+)G�|-5T�}M�X������`��k�9$XO_� 	$����CO�Hk,)��wT�i���nm�Y�p�oC��L���G����;�{��d�f|yLs����
4�5��6o^���-IR�~v`�����
4��4r�8�x��s,J�2BGg*�#/a�}�Q�[��~�p7A;r�X��!�2m�6�Z���94��hw�nmoo�;�����&M��!nGf�<S#����Fe�4E,�Ft^��8#
�W�o��L��7qbWoY����B�F:���c�
6��1]L(v
����NS��'J��g�"��|w��~O�=�h�E�4sHA�5L��,��&�03K���������i%��9�7��2O���V�1�dk������d�m���Z���_�,����31"�um��A	���������@��K�P����7�V�������M���.7��4�y�4���4��&��n��Y
S$�T��H�f�v���.+V���h���j�&cx�����LT�*'�1�A��+E�� oH�K�����&DZ�[)�RB�+z���F��Y������e3��a�g\��(�����N�n�eZ�����P���f0����G�i��<QZ��"����@���}�D������ #T��T�g�6���m�`+��&%���$������urQ����Q�
,��8W��usi#[���#J�2��@�q.���;�M���@���]�S���K���ycs�gM;�H�D������	�.��������)��W��Ja�#��������;�S��`���I��a�l��lD����53���1P�JQTI�
���o��D�7���������:�}r��s��T��9�j�R����z���i��0�^j�B�G��!G�9���}���om�+�9��Jy��c���a�u��u�����4�%Q\��c��\����m���z�q&~��
������{��p������9��5!�`<HU��:F��I�r"�1��
Cg�X��}�F+�O��k�j��I�3���f��'��vS7�M����7r�����vz��X5;Z��O��"�Vws�����n��ko�F�E|��E�R�h�m����������i��.;2S����-���'����O���wL��1[�
�y�)}N���6I�o���|�}6��a�)��Y��.������s���T�9��,JR9��<u�����Q	��5��8��g�*@Uz~��W�P�5��X������F�n�#5{;���B����PGJ_|Oso�����_�.�����kJ����8�~�]��Z��n���t0�=MW���c���,��d
�r&}2q/��;���0���3z�Io6t0$��IC^���x�^�?=����#���z�����'U�=j������$����gC��#e���zc��0��{�!�z�z��.�^�A�(0�F���\�X�w��ty�x�Y���8����A���y�\��(�hv��xx�Bu:�o��;xu�+�{��g��~x��{�������O�~����;�����UE�s��	���R��rz~%�����'G{/O�_u�;G{��{���`�F��o�7��v����0g2O�
����w�#�I�/.���
D�����eJB.0[�#�E6������������#0�.q�?h*d6�?/%D��������U�;��"��y���]����P~L��s�3J�u��0�(�G_�5?���!s$?z��<4��u��*G�/q�8����*CG���������)U��S,�����I2����,
eG
�#����D�
\�u����.������������2�W���9o`� ���G*�fIU�BZ�ZMC�U�f�������;�N��y{�;y�y��n�D�������Z`���y�=r�������u�`?Y;9�����?����8��A���\	k���=�@VDM������:�I��<��*5��J�y\|����]��_�����<9b�z�����(3����(�����,m��\�7��{�����G�yC>�uD>��dy���'~����#k�6����9��-�U�M�d��������Ir��T����V��'�S������:���{*����_�I9h�5����%k�k�:��4���h:��^���O�JNf��:q�C�x8�o<�/$0�!�5B��B�S��F�������GD�(���M���<����*A�#L��m"�**���A'�K��k���}�$J�����=��������X��b>��hc7���d��r�zP?N��k�����o���;A��;ABy����%|�4.hZa+���z��%�;g%�w��h4/�^����h����	:)�9/�.ik]R�/0`�:�����CG�xNv!����Y��<*3
�
U"A`��Z ��������?y*$xC"�g��,O���/����d�����c
�*�{��-���d6�5s�e���������6�`�d��	�����~��b�'pU��^Dk#���:���p���E��������(���F�`v�F��"���]M�����Z�c�2
��e�������V��x>sv��p��l�/No6�:rY�UV}V>�4S������J�<�����G��7zh����Dud���G\K��b����V~��w
������X�#���'��wP%��S�.�b���[�_������nzl�=��H�S�h��:~��#�����|�!�;���C�@-��%��=���Q]�����f���J����n �:�����_l7���v�������n����q�/���o�q�����O�K�x��5�;8���C:��.���4x�7��_���������_b���n�'�	���o��c��Nd`�����z|7K����Sa���6����6�� �j������-rU}�������2���R��C��������]��i����sV�������\�*uY����y�r|u%����{��A�'��K���@�J9���uT���=���m<�}�f����=:���:�C��S:������bd�t���}�hc��5i]K���B,s);(�m��D�N&��K�XFn?�
�\EJ������m0���w���n�q~�4��fc���\S_y����N����7{'g�_�Oh;��[�������^�����n``������9wp������f#�aAL���r�
��b@ /_�Rw����L�S����K��[g4
���X	�)(������.��;����Oi�x�{������iC����F14���P{����I�j�W� �vQf����;'��G�(�X<�E�aa�J��XO
����/(�B�K��#0x��.)���pXI�;x���(4�S�KC�xa���h���]5i<�x�!��
�������:�l��K���S���0�l`�����{���
<as��0p�w�x�3�����`�ahZ'�!j(:VrPv��M���H8q����-���C�
P��JrUl����������;"�Y�+�YPk6�0I��Dn<��������J�/\X���g�#��vEB�����G�k���D/%e[cJ�5V�0�,��k�\�5 �v���`�D��0W8VFX�_�����mUz��,}�{&���G>RFv2
oY�;!������l@E��oP��{M���q��8���a�u���b�#�w���pN�\�������s�{��pM�S����wO���%\�_�����e���R�]y*��G��%aI��iM�d��tO�LJ��J@���(���H�
��K69�I��X[��Sj.���(�$)l�da��)m�b\��s�jA�F�b�j%����>?WG���H�C1�UH�
������L;$�	z�|;�����S=�
��*���������"�@
8.��b�>��}�h�����4'�I�<���/�Z�t��s�El8d���x�&?N�<��bX^Xgu�y�&Ss��.�,$�z�n�p>���(��plIm'������G�r��7����,
��K�2�@T���F@������~Z�^�)//�6�>7?c=� )�*
��8d$8		�y���*_X���Tx���`#��N�������{�����wm%����Q���lm����K�y��IL?���9��6�As�; �t]u�����4�0���M�t,~��S��Z����/T?������d�Fn+">Sf3s�P����������rY�-h�%�'kE~`���GG�'�����r&��*\�gW��"E~R�1�'���U��}��r������y�o�7R]$�k.R�~���������������2�;`���+�����_�99?���f�OI�*=��G~J��+��;�5�mS_��l�/���=}��
���
���&�|e�CY�|��-��'$KQ�E3�Ky�������pG�r[��
�#������Gw����[>#
�����������k�	�=-�vQ]S�����D��]jI��>���>�����X�Yg�p|��z?�x�
�Z����'��X�1�-����-��si ��e���]���
m+1�X��i0���k�����y��7��J/}*%?���w;(|Y!��|r<j���������*S	�^v���x�>�4�'����0�����<>��7O q�D�V��I�[�-���p�}��
�Bq�<����w~�U��������l{� ���	�Qi3��5�O�51�>��e�9.�D��7RU�RWR�*�������[b���f�x�N�%�"�c��3���z\�����&�
�m���A�� ��x8p�u���-<
�����0��Y-<� ��jM�;���x6��;E��KKg����j���Sf������/���0>�
��v�X�v������j�h��(�;�l�H��.n��/O��/�K$��({�k"�<��#�b�f��;,�b����O��b�	/w'��h����K:/_��$�rh���w��6t;<�����[U�����n��s� �,8����?�&�R���w�=T�'q�}Y=��&yA@&d�q��"_��z�LW�^����!��7:J���//�����������_dgA���S����v�;<���UPQ��V��S\��<������#��"O_��k�;�������|�-�%_����/D-4,l����~=�}���o��p��=?8<���z�����l�������<�����U��H�A���4	R��Q�(�5Z]���*'�����x"����!���?��e������x�����Q��|��d���Y�>/I��Kw���������h
��`�&�0|���F�VYIlBhG�W�@i#ri��H��
{ E�����������d�M�_qh�c��c���������M2��1�����p�}8,��,�[�8)�]X�����=:�G�n���G��+'���j���X�t�VVg)T�q��gQ�C�����/�{C'V����~�4
�o(��o?�{����=db:���h��6d��({���P#)���q\���C��s��;�I�|�D$�����8Q�>e��+��j�/�����>�Tz
�g�O������m�+]��8�*�pY��;�=O\�M�6����DUq��� �	��t�1��d��J=&�J�9�juEr����bwM������m���O�G������m��+�
|�Mn��~�h���g�*��G����
�A5����	��DD���Q����)1������wD:��0�u�.F�=�ns��E8K�D>*��:�J�����B��P#xB���cWV�����O0�G�UBo�)�F��j5��v��;Iiw���k*������/K��,�-���T���	/o<������G��%�;�LKU��������*ywp`~�����Rk���*���}�o<�M]V�p��I'�Z���}j�|�9>6�Z�5`N���wbl�;�XJ,�BG�@^�yC94A�S^g�D(�5�~���+�z��lk#�[�z����%s��*���x��`�M'��|��?5�~1������z��wG������������K3Y�Fn/@y�Ii^�ex[�ZMve��?�u�������o�����j��v��{Z����'��C��@����>�0�B�h9�����)�b&��XD�������4�v��[3�vG��+�-���
�{cd�p�
0������k��������A��bf���{�~{�y{���x�\`�Rt�2��Z�������fMt��x}x�*hZ����/M�@��������� U����*��=��^a<�G�U�u��D�.&���9�t��1�D'gX��M\��n���f��(�0��bcY���cMk���������9@���0�(���A��I<N�x���{?
��\^*Uw���6��\RfZf5�|P��q�5%���f�q�DI�*��C�N�c�Yi��T��y����{��7hs8��
�xLC��������1�<���r�\�X���w�?�X%���U9�1v����V<�m+jl�����iY������mW�� ���W&B����=�9��!=4sG�sj�v�����n���)��<������Ms5��h\O�=�?�3s
�������w�[�����b� ��I��)��[�"�4uqJKk�,����XT0�hY1h�#�	Lz��u@g�:�&#%l
b��u����]������?A��_u��%=V���z�G��MX����5�@��w����\LP�:~�^@%<�g�����r��O�7��5<��	�^o2F������~������]f���c��}��O^��h2-?�MY��w&&��R�*�Gf��]Y�U0���K����x�F����+�5�x~�a4��~���{kh	��O(��i���3~��F�� <X�L������Q���;���8o{w�����WF���Hb�Zvbc=\WC�+�&������,��������=��m$g���N;C��N�K����*�x����������t��f?>N���F	��l:�����_��;�1�j���t��� ��@��l�bYq��P,��R�at�g��`���9WFJ��d���y�F�O,YK�x���9������<wH)eF��\����3�
�c��]3==C�Zt��bp##P��XK9�%����T�W�Al��L3fd��*"����y��ZG�s��`��;��9&.�T��/E���0:�Y�/~��~����p����S��/�C�O�KH<�P�6��8d���������o�?���S��`�=�����x��:I�5���v���t�u���h�V|/��v�H��M�AU[,9>�l]<A�P������{����.l���.c�GK�p���Zj�+�m��Y�6����v��	6G��)���1]�:��l!�E
,�Mv����9�$s��z�<G��s��bo���"������G�s8�w1*���v_�`�_����'�|�����+��b7�:�5��z�����l8_��Z�[
�!�
NE��rVs��������_�5�	��@��g(������������z�I����T��UYT���b	nn�����:���5������N m����V9�:�-h�k�z ��i`��f��@l����3�5�������K:j2_��tR�_]�&X��[����-k��D}�f�J��' ���"h/�[��lI�_A����nw�~�T|d��xD;�T}����~�������"W����l���ahZ���PI�j:4j�1{�oAe4���A"��s5d��:r���LO�Au�+��;1�^l�dIm����nBbk�v�z��8wj�9/�������W��{o��`��������!O�$�Z����-c�-X9���?d�������+au��H���s��p����1��-������s6_��>���z��w$��#��_�,���w>���1��b��g�@�dJP�V���yOP�3�T	���U��T��+ma�4Me��(wq�*�:�����~�^�m��~����U\������7%�e�u<:R�����f���;���' #������;�-9��BO�9�&uCw���sa��|��[9�v���j�~r�����G��b�!6iX�=����q�&���&�Z�V�C�\bT�+������ss�i6z	�h����!(���6������G=��������{�?���\�����V��gl������5��J?�n�`�/W����'�������j����_��(��@�+� g">�c�Sx|����%
rW�;���'�O��x�S�w
���x��	�����+a��s��B����yP�������F��;sh��������b@�%��O�_:r���8�c+���'�G�������y}�3�i^��>�����j���?��;�	[&�<��0��{�W���b6���m�	��cz�7���w��=7��A
��]��Z�� c�'RF}�5��B��PE��S{U��W!P��2|�=c����p�������������*�=sa�`�s|O';��G�C���H08g��"��x��&6��-�1�����E���Bp���E��{#
�.,
z��;�}!�7�X��������������:q���Cs�����/���i �2��J����p:6k��c�)�7=f!���w������*�:�g�2p�(u=�G�������?vhg��
}[U��|ye����My$�p�����%*�48l�� �~�(x�*iDT�RN�1����7�����"����'���{�r����e=����2Z������'������W'{S2�����E�vUw9d��RA�c
��!`��Yc{��
�J����k���GF��{�hm�'0��]������,�]�z��5=��RH�#�*<������CUo<M���s?������<�C��������>�_y�
��	0��m���<��';���|`WU�I����y!|UeRZc-p��T�}MHV����"�"���������g�<.��@|5����6��.��|���][��<RtH����O���&����k�9%���,����M\����#&`v�`��q���[��W=�������)���yn���]���	n����Z�,?�+�S��]�3x��b������������J*�F�?{�`�\�5,��rt��;Qo 	I .�������>��~�	v��jro���nO�����n��N���?��B'���#���VI�51o�8�Gg}���p�s��g�{����7o�������j�f:��r��K~CG������)�6QU�&[�
��
��m�K�zL������"s3�4��[h�����Ig���n�h��hC����l�L&���)mWmY��V��"iv���8T�����N&=������
Z
}��0\�R}��?������)�g]������F�Cr`�ef�{>����{d|�:����JG�O.��1�y���#ljy��7�a?"L\I���h7k�+�7�<:o�K��
����n�������	��q�x�{�����
0��	<��J����J����o�Q]�n�����t�������H4'%x�[�:G�����Sj����w������[�K�lZ��������>����#�'w�g;�i��k
������G��'T,�N�v������V�v�6�/�GT���2���;��^���5+^!{Jz�<��)@V<	 K6�8M�����D�)���Wlv���W(���w(��BPXZS(�d�a���%B�:�b�i���n��j�yD�!0H�xc5��#��.��a0��IyPw�J�Q��_��C�?Y-:���)�;9����qM{���2h����5��=�#������h��V�wC��s���^>�s�.����,�5������wo1K)^�C����	��?��?��k!`k�s��sf�
�	�]�p@k�_�������l��#���/��1Z&G�7Q}�r\Aq��U�G��{�b~���B0��T>{���c���$�L���L�e"��4Z���>��C���0u����m����
���*��c~�[��v�pt��C<9PB���w
��� �a�����{C��2��/�W����4����\,����<���k=��$7_d~V����_O��'��d��P���tcs����AtA��d�M���Vv#���pB���Cu�&QD����(��ox�n���'M@��n<.��*����Ug���^��o�����n$� aZ����wB	8�.l�!����z5q0��&O�e>#��t��$��4v45�@q�N�9�7�����3�7�%���G��D����b~��
wt3�;��k&*~�b(��f��
������d���|n�0�f�WF�'r1�,�1�n�]2�S����[}:��Y�����	����8hd�
����-�f6
�s]��@���#a�l8�\�9��	�a���LEX�[����))�*�n�yy;�����8w�!yI����Zo������������y�<x�B%������b#?��������\k���<qu9	��+A��7�C@y���_�� �wA��Rt�-����C�������L����rK"d:����9���s���zY��H�jL=��!������x=��t���~��=HJ����t���9:�.H�6}���
���9�K��7
��)����#x��;���O����MK�3�����YE�U����7�A����J�B<�Q�V��8��d�\bC �/�.B���I�X
�
����"*��k ,V�V��O����FC`�����@�����!�W���vi���#�/{d�K�	<B�� �����Ax�Y\c�����iI6<���;����Q��X�5T�<O�����)�I�D��Z!Q&g�����U��/y?D����������iP�o�{�;��I$�-�e*p�!������* �5�O������(��P�}��*���?�b�D-�,
�pE��S-,��0Tr�/5�YW���5����0T`M-�j�1T�I�8L���o��@v!��F��m�#�F
a������,��Y_T�#��8�*�jf@��k4����x��7��_�o�����c��/�d;�1�?�~��x��_�����"���_�e�`gW4�LN ��e��r����@A����_3��n��D�t��r���q�L�~�}������=� ��+<��f�w�
�=�U���d�//�����F�O��|����J����Uh�U0������7p��f���a�H�L����l���{����w������#8�'�����a��4��]���������{��?A/$�V:�k��x W��7z��`�sG�����wa���+�������(�[U��c4��I~�K��QI6�b�)LWb%8�o�qC:�8�<zN'&�G(�]�����;����>��;`�ml^p�n
v�2������[P�����<���=~�������
�L����������
^N�l���H����X��hHu�\A���=�h�$H�/��;4o���N��gp�L=�����@��"�S�2������=�4�Mg���;kP�z��>l�8�������Y?����0��X�M02B^P<�JDJ6����sCmri���~OYI�Th*�S���g#�"]���`K�H4����S:uak����������K�����
��1�%��5��&��-.`*b�,@��'s���2:�x=��b�VX����*�������������m��,�18�ch������-��������t�A���=�4�_�B����B�.����DG`��zPP��� ��w������{��m�@cm@+�tv��+�1A������6�$��-&��3`�=��)�H�R�	�E��~n���EZ�cVw��\�85���)��l&���}�Pv�c��pH�&�Bbw��+��Y�\��Y"��+OF���g|���0�����ey�<���`3��9��&�?9F��W�R���3nZ������W}`".��(Y�X
����^x[��������T�[%�?�H
S80L���N���;{�h�=z�9k�S�����������3�~��%����L��(_����7H�+
��Qx�i|��S��W�1_��KN8�6�k	%�0>�Kzx��+���J�x;'��]x�����=D����i���#���v'�H�z����qHY�	��+���<��_��}�A�S�����B�
�K�y��=�*�Ux��)h������AhhM�Xz�33���`	���*���|t��#B	�nm	��h�Py�!����j!`a��4��!����f���E.Qq�1=��z�^��wi6�3S�fB�����s�������kP�C��������������.E]�TBt��'~��s�����_2��h�^���8���[vs����V�>�����B����'\��lg}���%����#y�
~��I��+��aADHN�b�z�vD]���8���t���{�Y�5K�UhQ��|).u	a���A�o��b��z�M��$V��7�S�_���*�V�g���{�$�������Q�
���I �)���S*g8���,6����
�O�`�M�EL��|}yEL�)�"���1��|��5����eC�c��C���������o�)���(���;��R��[�E���po|��>���H!b�h'	�yBR���v?����Bk��Y����V����hit�E�0V�	��b*���T�cL|uq����O���:D@|���Ok���4!`!Mm~$;�2�<��|�Rre6�kj��#�/�j9����2,�D��, Za��!S�k���jh�L ��V�@�jZ��m�S%	�q��PVduI�%Ne�s�� vc��W��0N}���%@y(�F�bs4B	m�+u�����1UBZ�?Dy��*v}�0��v�K��[^�Yfz�c��!Y��U"�4tf����c	�u��9$��|`S!�C��nl|��9�w�r�Q?�1��?	��|0�����������	������Y��fT�X��'p��*0��]����H���c�Vrvy������9�S�@��}wT��@u������3g�8������F�$e�hP�h�h���oo�2n����G�{TB����#�����	+>��R#�,o/��������vO��]t�s�<��^S���N?�.&-b�1!i���g5CY������.�x�|a9���������j���8+�>����-L�1Z���W�G
�w{x�:[��2 i>��[
�����������������P�,?:��#bRrJ�Y&���j��+:�s.�,����1���-�����]\P���l���i����q�"(���-HZG��0��X�ce��������w�$���b
� ��e):��<<sc�� �L���JJ�P���������[�*�������q��Ywq��f���>.��q�2g�$@�_-=�������o<?x��s���,����9�J�y?t���6���lX���fZ?�!��D�����#����#��e�V�gJy��VUN{=�������3von������|��zc%����Z��E]H
����J����������������!��G��x�Q�L��h��WvL����`����6<�e!���?�oy�����dCb���mL;���9fZ���/P,N�������'���k�c�������&yG.66���]��6���~kC�7R@�]$�(&
��Z����-�;-5��x�)���W���������U">O����x�Z������������{
�7�����U�E����$��y{�.�-�����������{g��{E���)��u����>����w������S�.[#O�=q�b��u���z���r[���)�������rf�����]�n�&k�/�3�p�l��w�@do69�����Qh����Mw�:0.�W��������6Y@����]t�������_J������`�joUm;�zN�����������w��N2%���w�U����p�[IMM�����Nfr]/���u0��Z�t����	��[�����G�����a��V���#�����	QO�z�a�	 OB�q"dJ��U��>qo�����?y?������:��\]����v�����>B��u75�@���0�����;��[m����~��	���b�+����U����E,k��E'��U40���O�����W���,{��9���U���lD����-�h�X[;�L�-���d��-2�q�#T�x�ju�
{���ioP�*N�Eq��_�^�����w��Kw�9�Y������[�Q!��d@��f]F�?\Y�r_O��[�����?�D�q��}uB���E��EZ�E��E6R��7�I<�fh��Ut�����]�Z�n��Z(�u�B1���i!�PL)�r����f2l���6j)���l�����.����7�����k��X����fm�,��ZKk5�f{p��2l��a��
j�v�m7�=��k��^����E�_��aBfh��n�8�\������v��9::<�!x��K	n��'�`�6� x��)%SZ��?�����{g�������������g���j���wM'[�p	+J���Y�T2R�l�����67b��MqI+�vsk��=w{$�Y�RrJ;T�w���s��x����x8�=g(�!t+����p���<�;�n"������j

���
-
�R��3}Q�k���.����n�"��������Z���8��s�}��^�f2����qQ�����a�I`Pb�O���4Xq��q��qCB��0+��=��z�����3V�_uNv��i!P8����<;������}����T1�u���}b���K��>S�F�o��.�"|�~��7��.�v!��ni���3uI&B!���2�����k�Wp�T�%���G�����������S>��S~�K��f���P[��0u�c�����.X���.J<���+��v�
�VB�D}Z�rTN�L��<�tXN��V�}&�6�0���@6�g���w���|�1��F���Wj���P�������������_����U������B���&�)bJR�S&�.��+Yg\BT����+���]*:m�.�����A�+�?�s����3�l�x��,�)Ikz��yO$��`����F��vz���8={xm�������9��A\�)��\~�w�Yx������L=f�yI�{��B��.q^�Dm�����~<����|��C�	�#h|��?�w���:�b�W&��fA�W.�ZVf����H���dE�4����]U��ZwR�c��>Qg�}�i�	���F6���F��������{��y��z�'�'�_Y|`���-��N�9Q����JU2��\�J���&5b��"ou���Dv ���M��e]-��3N6��Q(x���H��qI�@/B@
�E�����@B`<m����Mr9�����<H��E��-��.�x?+�� ����t���)�L�;x���kk$��OX�Lx�|�(�� ����L����0r&��<�Z#�J2��o05�1�6�zf�N����+5(�E2����`������{��X������<������^5�sq���?J����@�J��+�J�V�4c����(�X�,9�����R��jV�V�js��vV8U��D�$��d&�R>�7u��.����U3��N&�Mv�0��f�d��(R�Kl�Hml����Z>���R���IF���f"�m��D�����=����������4<�ACV|��5 |�[����������A�3S0&�O�q��`.�@��F�Y��8"�,'���QQ�L����s
��)�u���;� 57�v.������w�n�e�|�����u,�p�.'�y�l�E\��V�
�C��^=��{��x���	�s����/�?$����r���������9$�H��yG�o&R�[�X�� ��C��Ed�%���Q�8$EkY,�,�6��\<_��oI�������%b���-6s]����d��Xa�o3�7s1����SbW��%p*����[��yw&��Ko����uRj��N&���Qv�����4�H�����@D�F�R��/D_r��H
��d\:��!&*.!M�l�|hyfE���� ���B�/=������*�����A���S��V%����y|���!��!��7����������O�
��"3��S���DJ���l0�������
m���-���<��#��u[ZY��=}Z���Xl����*)�"��k	�*����)�T��k��oy��@;C�[��Q#�|���(yZ\�"�`�_�7�
��-�%����0��L����8�$�U	QV�w��������6��^oCU��[
��-PS���_(��U���
�fVTi�5RuV��-v.�
���zw�i�((��H��%�����	�B�,�Za������"�������`�F�Y���2��
�b�)3zA/0��C���h$��ZK��Z���,	MQ]<]nEaj$#�
De��Z*_�������w��o�n/h3�����������R9c���M��`2���r����n�AP��x6e���ky*�y�0f	u���v�n{7�Sd�s��`��9���� �����JN8���{���������`��������kw��vy: �=��j:�P4�����G��I�B�_�ksK
(6�J�O;��=&Q6�!�f.;�/�z��B�Z7!�Z=����[��|	�����i���t�(�����o����}�;��\x���!z������r������b(72lk�Z����	U�4�� �eLQ�Q���k-u,�
����}r��������8����Y,�\'7��ao�s�}t
	����x�l6V<#V����A#r��?������
>�������-|.8��0/�|���B��C�@�I��LE�D��S�����Y���_��5�#/��W������`X0�B���Y��9N�N0�y|S!��2[���G�q}kT}�*��=�*���)���U�ej���g�/,��c~H7�&<��=��5�
=&&��������|������L()�5�y#}R�B�;���@<y0|g@f��|\qqg@U��Jy���h�q��������v��t�r������(��;6�e^��R�������U��^�����a���T�1)�e�4����"-�fe�����8���� �`n(v���zZ�O:ZUER�/wUTE:���v��H���(w�A�\����>I�������Mb%C,O����6�g1��*��*�������V�����v&ch/�2�[0���,�=/%�����M6[|�;7%=w7�CK�����e��Z=s��Y�QN{�������z�1I��X���Yl��+r���.��'�A�_�*u���]�G�90r�[��
��R�@u�	O6���a��N.�����h
���2�rq���p�cD~���R�B4��e*E+�������[}�}6+;lj�M-�q���Dk`�+���/bW2
�Z�+1�}\��g�a�����+Q�T9p�RV�@1Y����ZyfG����P���/��<|J�:�[<W��m��JP��,D���p-�L��G�hq�����\
��������i�#��O���KY0�1������[��|��jhc~}xsyZ7W����[(+�7u&S�|PR�d���n�����F7
$��dU:�HLp���}Z7��P�\���d��8�%�;6U%���'� ���y�;���>����LP����`@QX��%5G,5��u��%��/Y6��&�������KAs�N�����j�xA������toH�?N����R#��!�
Bz�D.��%)
n�������O�B���y�J"����-C�`�3u����;-��-����K}�KT"�Qo:���l��8|�l\|��H�rQ�_\���($?�W$�TZ������/G������xr�LW��;8�B���L^��{C��
��*�����b�s������l��+A�&t*E%MlV����QA�~.dUqBt	�~��n���#'��)����b�4��z��Xo4v����9Ij���4
��$�_����n��hJ��	�8�����7)����lm57Z��d@7H�	(z���h�����,P�|:��[�Vt3����n;8R�_�����r��uJ�+*�����yS�G��:�9�R�w�Ja���F��q�=�@��^]O?���:l���LK�7��E���>>�iJ�(e��<���/6�G��0#�jm7lk��l��I���a���H��f��������i7w�[��`�t+��%q�=P�~�vuU���RIAd�TY�{�o�PKL���Q e���
�}�����z�	J��>_�R;=����>�
Yo�w�F���4���������1b|oo�
�;��j��&�*(�/tNg��r����:�f��xj%F�*��`O�������>�'�Q+�t��rm���E�P@p[�i��x:�Df�In���D[�T�7��jofN&v,{�|X����!�cd�
�`�0 Z8O�N^�x�\�oGS�F��;��B��l�F6u�����n`����x�'����,\��K��������|��t��B�3��C�[�xn4�T���4x0�gP�A{j���\��X��<M�P�eb$)�������]j�m.?.��3����Z�}tM]y�"	�=�t��d�����R��$��r	'[g���EQ�������6�{��;k��;k)����8�H�y��<�o�70����3��o�7�����l8M��u������0/v�1�@�V��*�	����xn��z�@���~hH�b����z�in�����u��'^��������+��Y���9K^��t�r
�;b��w/���c�d�B����^$����3x	��W�����uU������
�|����N��i4���R�5���z,��K'j2@�U��.�ci��}�"�$����:��R�p���:��T�X\
�8�W��D�3vO���2������$C�dt�)�����?��%���o�����ol����i3&��^�~�T��K��J��x�������J�6�u�KI�k���F�x/�~��O}i���%�yo+�k�wCjKm����J��C���X����'+_��_����H6�I�Q�m6�������mG�
��K{���d��ya��S"�k3�l$�,l�I�)'Rc&Yy_����L|�#C�d$l��ft8��4���$����V��������kE[.�fq�4��$\����Zv|kE^5��b%�VK3���.����Wl0;�����3����ZC�6�K�M=������Vj�k���t���0��Joe����yy]Z9�1�:�i����%R ��_�;��<�K��Q����)+�Sv�M&�Yv�z����%BZ��[����l�Wn��r����e�xz�������|��N�H+V5��)BH�`n�5������WTr�� �����u>�����0�����
�R�O�������i�^)v��4���
I4)&D��cD��`�M����.��`�D1Y��'�mY>1	�%���g	v%����H7)�������Q5!Kz�w�N�p������z�!��7��Q���Xt�l�Dy�%S+��V}��M������3�
��H��p������z���Q�����m�����!�(��F�+p��C;|�!�����n�xU	����#�Uw�S�T�dEV���zY�x��8=�<�x2�i*��r@� �����k(����]��j�=�5��e�������
m�f�T�wk�z;�o9I||Z�U��4��L3��Yb�x��(�p�_��Y��M�S��1��/"r�:���)5B�+BT��S������	���f����W0�L`pS�Y������ (c�G�L��,o��DL��*sr*�(�����]��\L���/J�]y��%�L��sb$@�1�����RC���}�>����O��F�l��e?S��������Cx	����0_��\X�.{~q��i���~G����W�;�U����Mv}-���Aw�:�������� �r@y�N��� �\�E&��L\�;�T�tv,D:A��7����/7;�q����u��*��b�1�.-�^��5��Io���R���<=����z.������nM|'��.��V���d��<����V7��),?2�
2uU��]E�|�U_�����8Ty)��w��t�����Q����������w
[EV��<�����e�hK�c���
��!��@Mny��V���o�{2u����{9�����j���?A�������
���O�b0t�����u
���`�wo���^w�v��\��'}��v���z6T/^�Z�
�H�Vc�"/^�-U?���w|r����g��w�������]���$P}�+&V���3��xq���S�Yx��:�����H
����w����T�[ �d�t1��W m��L\QM������!�����]�PY�Hb�D�MC�zw�8�\��;������,x��A�
�\�z�'�]59�K-d��F��
o�+�/N:������L��y8Q��C�$3��$��Yh�D��U����R����I���:'�����e�,9��U��@��a��2���|~#"����[$����Xz������P�x�&^�&����\2���a2Th�������d��<K����n�d;A���2�0��fZ�6�8��
7�U�v�������E���M�{Q��Yn%:HE����v��H��2�&iCAw<��S�&������pC�=�j�LX������w)>��Ph�gq^r��J���e�����W <�<r^p��3��,qz[H�:�������}�BVK��[�(��X��W�\�99�y��;Fq�,#_����`"6MS���7x�K�����aJ�������e7
I�%�A	����JZP�O���
X��|<Y�F�M��?N��d��jL�p����`�F�a=��������F�����n�Tu����4�q�����)�R�$e����l�����_�C���e���D�����������w&�v����L�c���	�K��U�D�]
�X7}��-�P��R�v�@f�~��i���#Qf�5dv����,�\m���LG�s_���:�5�9]�G��6��>�(w�B��k�����8#��w{<����\�{���+����V/�:�'������������s�\����	h����]� �?:���pr����#�p8�D���7?
�)��S$�|i�E�L��	h&��s��D�W_��C��
���x6�����d$��@�;�����Y@{�<kV��a�a�5%R��O��d<Y5C���T��MVg.o�������:s�!6���Q�Vr�������s���7�����������i��2��k6+��YA����O\2}�6�
�������`�0L��$LE{�$�oODtn����w��L��G�n�����-I��_����]���
.B�nx H�Y~�R&�>������G�o��Kw��s��\�/�r<���D�U^:F��IR�~a������M
�;S�c�*��n6����*s<k�-��SR|��1��S^;�
6X������:�be`�t��SBK�U�j SO=2�.�����Oh��n��
bmq���=>�&��\�Q����.o�CV
_I\%p�ln���-����q�'
[\��pIu�������w�����#xHy��RWS��_�N~:|wB~=�}��sdZ��<<x�w�wx��������������a���!��
~�?�����7���)~����{��"dK�s+��:��p������R���Ap��k����q���5�����7��������,�a��B���[��Sx}<���������4>�0x,�o�O��Y�C��
;������C�i�����2�rZ���i��Y�c5{��A�2��V�$�f#8XJ�r���C@������v�	��9�&��l�|����Z�i�!����������d����K�4:�����e�z�u���~���[0��G~*�U),^����7���|�?�yJ/�\c���E��6L�
�g*{f��:j��y�����|b�Uc4b���j[�`����Q�4nc���s���L�����[��w�'�����������G�����X*!�o�NL��#)7����A�����������'����Er����|DNS�0���lX��p�C������8_V�{8����S����N�yna�:�`�cU,9��xJ�wEVh��9t�7 ��P����w�����0��`��Of�����Hx X�@4��%
�^��C��[DEjy�*���
T`��Y��yf��f������
2`��V�c���W3I���	W�M�0,l������o0G����e��O���8)�� b�-i�%�p���:�R��/�aso�2�RLK��CLngA���Y�P���}�8���de���p��H��N����c,:�$���&�1KS�d�����������V'%��2vM��\�MV��Ci-�W|x��jT���2/���9�T��.�W����8�d���e��v�?/��D���U������n�_�.�-�zA���n��q�
-�����U���7����9�bj(�n��0;���d�;���\��7M�����G�u��c�r�
[�-9E��������/��/[,�My
�?kI� /;�����V��k���2X[�?�-~!H��$`MXS������������d(-JK@?Hv���:g�yZ&no<���W�	���� ���o;�Z����#U%S�����ag�_��W�#���A_��� 0�"=eUb�����	���iiG$�*���,����I����o���$|�W�Lw0��
��	���|��O�T��4S���j�K��"��_������k�;��F�7-�#B�Be2����x���0�0$����gw��U�W�N�*Rc&��I�_H��������������G�7?(���~��p��.Y�8bm����
�����8�6h��^?ZRBK�*���zn�6y��,�����%b$�]���f�6��3e
g��}��i�����N��Z9��������|������fl*�4:}w�{�l��I.t��n�Y���"YH���W�H��{a,	}dW�P����Ov���#�DHeLH�aB��~�+S>!'y�&R�����<���hw��D���I���:/&��p�����+�RE��O�X���7�N�<S@�xbzh3pXq4c��3�x��b@J3L�8d�SM�|�6����_����/����-�NL+LL�w�$����s��0����J�`�%S�k���g�Q�;��������@����W����'Nw�����;��Z��7�����5#.}4t0��Wr@������y��e��%04��Y�~]��~$�+/���*���;?��X�F|g�9���[]XJ�{Zt�H���F�0d9�
�S���0���,�����)������!v�`�&R�L�7$�T���E�F�����u�T6����X�Z*M�(DY��T[>�\2C�S�&Q��G%J�7u��eHA�������^�?��<�l)��iC]�'Wh��=�����R������QG����s�����;dU���W��#b�������h�l@i2u�2���������u�����HD�����]YB|�}5vF��#Q����KwzK�e����p�w8�WX��p��I�� �+������y���������D�����(WK��i���q���P��0f��C����,eK��	��.d�z���^�|�i	�c�P2�q^��)��3B���K�����e&�z&F�erb�sb�g�T�[����x��<���$X������[cM��B�\*cmS�6�o��R9k7Y#������Ia�����xT�������FuWt�M��D���:�3�u5JB@C4sfGOB���L]��A:�T��t���T&c��4G]�J�5e7#��K�i���O(�UL����"���'r��:� ����m�.�������Da��t�{�989K�)�}v�:L���z�����X���������v��n5���Mq�*��6��U�����f��n�u�kY-B�9�x6�����
��,��?���y�*��VW�������V�
n�+D�|paDdJ�{|r���>E�g�X-P0��k��L0�^�,|�)����������c����,�/m2@3��%"��_o,��+q���57p.�X��n���K��	�f���?�������Mm��\��Ng�� ��~_����($�6�UP���"ON�x��X�"UA�����Q��� aJ�b1h
�(����: ljL����{�:��?��)��0 z9������C�	qG��=���q~J�����g�i�Z�v���QR�Q�jl���m�����b��oo�!-~��!�H����+�z�v:�"<XpD�R�{I��K:�C�j��a0�r��O.�a���$��\6|9�whs#�����
l"��q_��-a�CGS���H���I�}n��T{�?��Cdt�Z�on��tc)�|�v�����	h���h���4j/��LT���2|�z�H�#+�A�m��??����I�����hY���3�����"�#\y�o��o��4���a���,DG�"���A����?�_$��+�yn	Lv��N���G����#l���<2�+���9��/�����b��JEM�������U�U�U�0��Lh��V���20>A	�����/|�x~�x~�x~�x��M<��_��_��_�[�o��o���s���Nte�����0��|�Hh��s�^��V������R��������%W��+v]�iS�}��^����������O�
�m�R���Qm�u�j�7��H�����\o*����nw��z����n�Ld���z7�E`�r��������K����d��Ia��\0�K�9Oc�`�'��N��7�*B2icv~�dw���}���^�f2�$�BjX'd�
�2�����*����`���a@a���"�Tw
��/��u��dp=�]��,��D�1u|A�t��{�������Ix�l��\S;{��7��J�Q�N�F��S��*�NP��/������3�t�4���������\�V�vAp���Mu�P��.�}��b���)��d&d���\�<�Y�!yt�gFfW]���w5X��C���'����C������<�^>GL' ���@��8���QVXtmx�,^_�BH�>���x����g���D�G��{&|H]� �3B^���[eN��S#��8,�K��R�Sv����I���%A�1*�T�+lFF�O�"A[������p��V�����3.$��V^���:��$p����TWvT/���T�gT�@��m^<1�%�q���+F�d+���a6 N~q��W���u�<���(t?���G�e5���5=M��H���`��9����K���[hm�O��q�gP�"D-\��
]��U/7���N�����`+)�]�����O����9�0}�f4�syh�-�<������JF	��/�LM-]�E��.E�rTgQ�%+��0Fu`�(��os�*�I���;?{�$���k7V�z!�����P`�+u���Y�M��]
0V�jR�.<3�O�Y�	���oBC#����f�^eo�����r��"��}4�'����hb�q��]vo�gw2��	����J��|���I�X��q�|v���>�m�t�;�[Q��1���62����
�;�� Ma23��p�R�4$)��d�c�s��-��i�`B5h� ��q�-��||:t�i��"�<�?+����epu�8F���������\.�F�����!40fDe8������#������|K;E~V�������a�,����Q���[�����#5�=��X���<F�U����W������3��1�Xcu~�UX����%G	�������p2N���G���y�0�R�zJ�����������:
����$�S�N*�*�Y�*dTk�7�-�0bY"�F���a����L�
��dj�������|\;M��%��Z�Jt��{y���r�����)Y����J�^P�VFI-�4��0m��N6��}���&�Df�&��"�l�O��\dd�����#��2��L�@�q#Dp�!xg�����;>�1		$P���k��2_��!�*8��R�d��	�����-E�k4z2��c����99/u3�y���{���e��idg���w���-m+?�BX���^����h����O�'ai�"��9zGQ$�CI����A�6P7BJ���������J4��~|C����!'!�]�p�X0&�`4!�^���a)\�beQ��-J��9����C����-d�/%Xm�!�2X����M%�=��#�6#	���|L{J�
Y�NE%��tK�5�����>�&#Id�����5�	9:z�C�9��c4�$R����������T���/�"�Td������S����R�m���aVY�A�02u'#��/=������*�������G�������`���FY�T��������������="XAB��W��Xd�"����l0�������
m���-�{K���y�K7�����i�|hs�0�V�������% ��J���|S�f�v[��-�����n�F����/0���iq�����Z|��0*��.�T��o"��>0���C�h��DW%DYy;���_�f���*z�
U�Ow)���@O��~�(�Vu�/47��aXQ�
�H�[�����+�������3y`�G$�3�$��Rxah���#Z+�]���rV������B���VfQ�a���2��a���>4I	�E�������O��������EW�F2&�H\v:��r�>2��;��_��[��B�6�H��ZC���Z���P��U�'�8k\/@L�_��A����x����r�������M����^�s��K��e�{��4p<��8�9�f��J�������<��d����YR�����������
&�|2n2�|?%�kw���xHj����[���t<�h�;GT)�M�j��P�6���b�t���c?���i��je�[[Y�Y_U���R�o	��T
Z8�@	������ L��p���7�a�6g�o��0pa�xD:j��#�l�i�\_c�����8���mp0"��We��H9��E��t3����e�K�zVl�l���Y%�g-sb��5�Rk�m	~���3��vC+����X���HyQ�������#p6vHw<���>��{Z��$G�f�����*M�h�����(x�48]�(c,qgC����S�a��������@P�y�)>���$��4���t����O_\�aBInLQ��i�=u"�^`��*Z`�g��8m���M���laVsJa�v���}�0���D������|��H��QYM��|�$���S�[�P9-����2L�cB���R.%�zzV��rE=�92��������3��>)�V�E�P�/�j�rW���2�������
��^tM���si"$���Y�}|�����{l%��������
]d�!��H�Rw�^����b��q����1���[�_��	E�w��g�a����q^X\`�-����K$����r-�fe�E�W!�r>��OC�A	@���e�}�^RU�������iUa!���d&c�s�m�)��;}?��wp���E����\J�����3-���5��f�,n��Jz�
�*jTqk�z�J���`@F;�y�%X��� 0T�@T{nb���G�x�j~bz�`HG���i� ]����d�"iN�"�W3�i��j?��r��~&�p(�/8W�X*�ts���d��!o���LHh��Y(u���]%�'B����t�Y�}>�>�7AQ5t�Bx��y"Z�+��Zm��\Pa�t�\'>��F�����Y��13z��B�����Q��9�k6������Tc1���xy�A��V�kZj�Bv'���El������x����h<��5e�.U�\���k=������_�X�d�rh��L�j�,�o�m/\���q�]�{�<�V�n�����Y�--��8:t�P9�
#g4�HJ��a �.�`t��e_�+��q�;u�Y��bM�7[���B�O�X��_M���
������7?�j/�������k��{�%��������JG�M���#����d�e�n�����f��%���R��L�$G	h�x���}�';�6��	;�_%�_��8�t�>�i�8z[�����M�Z�����EqU�� ��d����//}2~��1�|<��iFh]�1r��d�0���{�x����d8���O�K�����t�k�XnD�� �rBH������$��M~���?�0�����v5�I$<4��%��=t��tp������r1����D.f��t0���|4����;1�D�%����*��k�%�������J�~6�����h��RO�����O{'P�s�w���!��"so(c���W%���\z��0;�w��0w%���B���#U���=��/(����*��,�O?���7{���?����C��w��Fc���H(/M
�S��������;�����9M�`7!gt�{��"�h[���Vs�������i��j����������"��'t��jE7DmQ
Q���#�.)����`l�:�N	�aE%���W3o�C�HPR���S:8��|r����o����������sZ
����'e*��f�����O����	Ce�P�l��'�P�����6���Y���mm4��z;At���R�/�v���5�5�>�;��N�bK vi`-Z�$r/������j��S*$y�����+�DP�n���)�v������'�PsO���BO�cCI����_�
C��D�!�����H2��������uOF������y��XCnV�'u�sB���+f��D+��+qBV���ZH��@n��q"���Y�C�����#(��h��5m����g�MW��h�,���8�f�q��b����e/��"�:�f���=�����zw�2���Z;�:7Z��a�C�e�5����kM����C���fLA"�Ve�J�^�=�~�t�$����I���)x:�8��?��{�G�O�
�<D�cy��e!,��a��X���Bv��a����Z6N�Bd��������\~]�Kg����R�h�b
��+��%SO��0E���j$���^�K<;M\�/�$}?V�}��i����Y���Y�����|�����'��~�	���>�5�O��F}�	����|��{����D�PZ�K\�^��\���O5H���C\�3!�8���OYoH���
	^�(��Xo43�8=�;i��
XG�"e�a�������y�d�n��//ba;Y9%��Cf���$����K:����wP��~H�_];����~e����<vW�~l������^��a�4��F�z~-�^��=��rm�t�&D_5K�"j�^N��)�
�9_����>0e�W����]NE�����y5;��?#�g�$q+�b�������dh���=e^�A���	2�6~��-}�='����VS��lL�m�����v
�t��<��|f���E�K�7���K	;n���F�xw�~��a}�����yo+�k�wCjKm����
��?C���Y^=]���s�/���RD�$���9�7��i����
H�-���{��d���a��<s"m3�l$�,l�I�A'Rk&�z_���L�	�9#s�h$l��'fu=������&����V&��������kE�.�fr�4��$]����Zv|sE^5��b%�XK���/����Wl�;�����3����Z[�6�c�M?����T�V�h]���t���0�ooe����yy�Yr��A������@�W�N%9
�fx;���6��DeF}���(v��b�c0���r1W�~�^s=������s��w��.K����`D>����4y��kz���	=�(AI�����#fDNQ��QT�.������#�������q||��@��������_J�-�4����Z����Y��'[�b�*Du����g�Qs1�x��k�2�g���M��5���m�r�H7��AO�q4�g~_�i4`�~@X�y�����RU$K��,(��NFq��,����z�[$ �o�+��1*���(�%3��X)L��Dlc�����R��$�3���I��p����S�z����oj���m���#=�H�>U�k��F];|�.�|�B�o�$�Ui���#�Vw�!	1JO���B��0�l��qz����d��/Ubk��N`4�A3���Pj5�����n���k(��|������J�F����-���vH��R������v�mV2N�[���coF�����:���^o2�������~���!pBj�N���=9�Qa���M;���b@I���$k����	����r��]X��8p��2��!�����VK����2��R�������I��}�E}���������Q*��H�\�nt��Y��� �6������+�8��mT��Y$��Qx�����P�1�/���<6�K��!6t|��)�8���MU~���w�����]��tcp��
����Mr��kK���6c�|C��g9 �r���`�T��#�{&���Y~e:�	�R"�!H�@�K�����Jnw��:��D�@>����t�*���k	���,����t#���p���3�\��s�'9����
�]8��n��:�y6����n
�c`~�1f6��d����W}9f�i��Q�Rh�x���s�!��{kH�z��'�
b�Al}�nAbMZ%
6����X���P�/;RY�*D1�!������j�:�y�MzO��7}2q/'��z��P]���'���!|���n��+#��]r5��p��F��2�������7�V���V(��I���������������~���v��x�����������|�������� 4���<cbf1�W��m�I�	Dm�L���'}^>���;:�;��5{�0$�n�8�9D�B�"�)^�syi)�6d��'k��	��y���Y�A������X�x��$l���Z/qf�L�����H���8�L��s�t��X�K��7�w�	���5���	#Y��#o*�����1�=&7�P��6�)��x�bo%BH�c���eJ#��������x<t�M�xJ�����p}m=�j��Lh���������%�n,��"H���w� �$p��i*x9�`����4�r(��D=h[:3��4$���2$pB�{�V��?��f~<S�)3s�d�G-��S�!��?'kO2"fU
�@�Q��@���o�w�9�K��|{�&a��7W����1
f�C�����J��A��������r��N��R��v������.��hQC��Yu~N��������1��	�lD�`���(���X��A;�/��Eb�
�Q��v�z��0#:�H���b*������U�����bY����o61��p?��n�k"����_�m\��F��LB�g��'.u������}��,����RWX����p��
�s�<���t���7�{�Gh����s�p��3�h�����]�k GZ���p�����g8"�[�+�&&�R�'QB��H\4@;�$J�3qp��3t&��g|�Q�`�*�#���l������HZ��@�yN �����Z�{�\k"�s��0C��$�.��N&�������3�ED���>��x�����f���e����h�t�1��<hV�J��o��m��6�H����=W+�T2b��;lHm'h��x���{�&n�#,����E�� ���hJ�$�*��'In}"����f����Tl���8t����G7�{A"��z�/cWdnp��(��A{�����80��q�����>:|C�_�#����{�d�z�w���`��|%�|��.��>����v��K=��Sw��� �U;�mR�E''U���:c ?
���>b�%�*�v�E.��O��)�B&�N��Z�*��m����r�[
da��{#%��7@��'��k�K���8
@K��d�yN6�(eP�����b��$�XZ:;~�m�6Zai_8���-��G/ZK�%�$�O���s��4�)�l�Z�>&����t����z���m�(�yyx�j�d��`w�����������F�����S�V;��Ji:����j�����4�$�`[T��H���?V��SB��w1S|~�b�[��f|~�X�$s>�}Ly������x
O���q9�����><������c��y�}x
O#����bM!�V�����>���s(�N��?T��=^	��-����F���<V����&)
�jji6�}�%���GLV�����Z4l��J2u��(� �${hF.0l�J��L�U<��T2��X��iZ[��%Ha���+��(!�����qQP�!���T��RX��y
ivK��|5~��>^(�����������������Ca�YG�y<���j�������T���5����0��;[t�kR7b!?w:o����t����:�/w�w����-�$����2���(��,�"@��70
`�@����;�f�����u�g�t~;���3u�d8���a�g�n��Ks�vE�><z��*�����lX���<�C������2��
����O�)���q���<���0�Y�g0L`����
�P7�,�F	t��m@m qe}��m0e�z]o�M>��.��E}@R�)[�T4��%J�r9ys	�I-����T@^!�
��7��\ �Px��;���$8�,�9:M��8��!�K�����Y���>��	"vD�S(?�&e�2S7D��-]�����j1^��������/�����n��;"�i�\_�������i�#�:���<���h��H�	k�c���H�{�c�m\Z�,hd/~I(����d�������4V�b�
����5���+�%��byt\Y��q���6-�g7�v�?7����!���m�5D�q���,�9�p���-\�x���[$r��FnC�^��� +l��U��mA������x�
�[�(<do��P�N�/���p�M����*���_���X��B�=q�>�w���������-���AS��g-�d����|���
��4`-=X[k��B��/)����)k���������PZ2���%Ci	(�ia��v�p@��� �����'}v���h�o��~:��m'8LC���p��d�#H���.�K��+x����3�Mq���_���R|�Vb0� �>-��D4�?=���P��A"�?������]����h�iO"Q���v�'��%���d�m��\UKH4���]����(3���]����F����h�z�r9*�/Tj ��B
�,Hm�9��(Ar��<������*u
W���@4��<N��B"fEd#�n�5����>>�%����t��>����8T�����A.����^�����v���Z�������ZPY��p;�8���`��5��p����Hq�������O�����C�5�CH����j�'�L
����p���X>k��J
Q�������?��@@w9'l��kW�.t_�n�Y���ByH�(��gI�Qza<	�d9��ZO�c�'�?�w� =g�."0M�
�9�u��Lh�4I�I�_)f����������=j�*/����P�d����
j�RM$�O�%e��K�[d�����*��`��\X����8������!6������������W2������`2yF���
�#+DN���~BL�'~{7�N�4J���D����t�>Td�*�o��������'Nw�����;��z�p�K�@�	l
�Q�>:�O�+9��!�lIL��b��� >0'�]�-�����?8�#�_Y�����W�+-<��a���7�;S���.���g��Fj�D������'��6jz!��l�w�N����Dt�0���W�7��325����m�p�o2!�w��;S�5U�t��Q�!��b9]�Y�")�1���J������=��c-&��M"�����tzS��`���
�Z����5@��!��s�V�X��6��xr�������:/%�_�u$E?9W.����CV��}5.�b��)�L��L����}tE��p� �S��WW�n]�N��c��~�E��s#]���J����`^D��JC���u�H����������z��w#���'�p����-�L���{AX������.�Q��������$�x/��-s���_{���B}����;�D�9:g��="�'���iC2R?\x%�q0�E\�B���������`Q
@�/N�S@���	�R����\f�tf�9�9U���w^�v7~$?"C��k$A�m%E���[��7��6��[�������d�Z�
�s����mb��p}4���C������Gm�}�)V���Zg���BM�g�g���Ix�RZ���8��������,��f�*D��D���wX�����������I�Lc�x.? ��?�����N?�08qa;�K�tA���QX�Jf#q��{�989K�)��w�:��JD����<�CYQ*���(��S����+���g���t5�k�v?W�����u���D�g����uiy��g7Ot~{��_�/iO%��_B�fWj�#�6(��s�=�;�?�6�R�s;����%u��dS�!���1�O��N�(�)@=_�}[���/hS
���Wx����[��I���`D��gW��?�~
[�}���'��G������`�2��o��t�C��/����JE���n�<��jA��F�
��F
���Mg��q���F�Kpk����m�`�_���'����,�(�C Q�8��R��H�
�����?��,�g1"�kaaV�����,��M��Q�E�]�^�k-E��8k01������)
L��7 c�f�.F�F#��,`�t,$s����z����o��-I];�T2}�&���A|�J�����}��v� ��ri��ZDa\�����L��(o�o�
o�:�;���	� ����^E��,#5��(��<K�ciX��F�1�S��J-�Z<�Zjj���<Y���f`�(7�$�E�0Ar������oO�u�1>P������G����G���?&�����������Q*Dd�3��v)\
[K�%c5�/\ �?n�
(�����K�yG�m�-�C?��wa��iV������c�MC�=�����8K��L�
U�������.��K8�7e>}J;�|������6���E>��<���Gq\�0��c����b�5&i�$�2���j��	���N'"�F�$OV��7�hN"=Y������������CF9���c�oe������JZvS�'Y�6�.9d��MI�*��P2/�t�9
�)9�^��,�8	�����4>I��6+�}�?����y�0�,��$�x�w�j\��H<�I�R
��,Q��J��`�
�Khsi�y���+s�L^%R�� �u.��|u�N�d9�7�4�e��e�����C�q(*6�?%����f�D&"���<���zL��	>��/��,��c�;���+�	S{k#���`�a8�X��A��*�t��*P�V��&�Y+Z"�;�y���}����>��B��3Pw����[��i��'�r��-���o�_{��=>����}v��`���z�����a�ux�%
3$`i	���'�X8F��	��H��0F��4*E�&	z���B��<��	��R�D��U�s	�+���Do9�r���TO�����s7�����ja���<�K�b��?�u��u�b8O�������7��i8)rNCC��W�i1�u��BU���l\�gh3��\5
vI|#S��6�����U����Ag�������<%���Bu);�Zz����M�	ul��
6,f�}��mJ������aK�����%
=�����{>q/�R�7�M��(,���ZmWiyw`�;��w=��!*,i�3tF=9-�4���?������B�"1��@.��%)=l��
��
;}����{)�3�F�{sP?����r��]�������;q�/q����K����}���J���\�U_����������?���Q�
��z�'���[,�� |��.f��eD��i���p�X
�)����~�[�L��4:.l'����`����4���������w.&@TF�Rw���`���������rZ{\�����L�����r�����d�t[�$�W[O����d�
b�>%�d�A����d��D�*��"$�'*n��O��eQ�,�*����Z����7U0].��[#�eHo
o�������z�R1
�/`UG�*�� ���J�Q
���U�"T���U����A�Vud�,���"g��)�lq
Q-.�.��m��2����,��$m���B�[/�x�1�%9�1O���W���y&�*1�����
��-����D���]�j���h�:5
����gG*)�Sd0U���4�����no���1���zN��J"�.������vNZL���������Kv������9������r��!_H�%��D�����]�������3@�������*<,�����1�o��;����&��6}��F���!Mbw	~-���E�&�������1��=@���J�'QX`&����RcY��#Z�����US�����O�k$�e2g��Z!�a �T,�jQ3@��v�Z,��
z�K`��q� )\^�`�2a&��X
C����yx0A��D�,7��*h|����vil�b�Q7�C3lFc������X�0
�(��2h��2��)>3�H�Kf�ru����h
���P]��pOpn^]��3�X����,�\8;�;E��Zdt��a������sF��mj��(���s���6���f����Y|(}����	��>���ZY��6��X
�k�>�������v^����W�#�������
!���3�d��|U~�E��e#�c������Z!�wV�e'�k�,
EzgmI0��FCz���Wj�47$���IQ�y:�W{�'{�F��K��ZgU��h�O�L���v�TR�O�n���U�V�]�����syy1c���@������t#gr{����6�^G)�N�g�Y���V���`58;
[��	(j�j�'��0�Z��Ln����k^�&�:�J���4	�0��;�.�c>����!�Y��}�L�ga��a�u&�%0g��D�-��@~sc��\�_��[�I��o�o�W���*� �����E)=�J���
mo�B�{m�����[�q�M(��=���
��e_<O(�^�(����J#��>�}R@�����6��&Hks��M�V��P�@��g	6����[��^P'��	�l�Q%d7L�;�����1�:�\g�{OB����#���.��4�HM<�C��
����������z��l�o����l0q�L��@����G���c'�:3}��������P*g�����N�����N�"���n�v,�(K��,���X�=w��#�"�a$�z��@���.|w0H�z�{a L�z�����W�����-9�n�A/�\�
���}H@���Q�����
d�/�"���^��.�K����x������W������}V�Gi8OR��On��;��p3���8���T����H���z<����PSpeTD����N(ax��:td�)�KM{yrh��0��^^�n�y�H��J`� g*�f�x�����Ao�ZqeT�p�� ���!�*�o��RT�(i�_,4kS����[����`�����u5�=�(y��gI���5"�/^_�Fz>
�&�������d
�����ks%���L�+�T=��>���&{��4�R/+q&��+w!n7�V��p{}���{K
���<��^�e
7�����!���sV��+s���4���N4b�����\��$�@����������E_�(�p���f7Y�7H�.ei�����x�DS��wu��
���[��
���A]+MYMI������*^�"j����j���z���TY��TIo|u=�S�J����7=�-�;��guQ�V��
�RvV��p�n7�9�����8���B��rG���j���kj$����V����[��-�:�%}
�x.�J+d@�9����~U���������w���@�>
Er�em(�B��"���v~��YX���]��_��hv��"�'kf�~La��K�?�W������x����MW;���e�W����!Q��e��.�N|��'�N']Q3s�tS�u�yN�8`8����"��e�T��X�%B��Q���<����$�d;D\��%N�&9�)��]����n��G�������M?��C��6�E�Q�t)���HL>�W�����L�������Q6��{b	t�7������?wN"dw�0y�$�Y.�J��#�#��������g}�$8���w�@T[��e���h~�Ehb�Y���`4�j/D��N$\:��M	��Y0�Zf���Xp'
D��`��O�U|�����Z�(�$��zn�SO������e�D
/8
/�����X�N�J��xB�r|1��K���pQ���b�-��%/�g'!2����'/��Yw�-����7�n;~yZ4�z�� n�}��Zm��*�������H�k�=+��K#U]`�"�,�������X ��:�;�y���>�W�L����O�HX]�(t�$dV	�G�giFz� ���*�SHx^�2s����S�n)+f��.q�Alx�9�dgEb���|��;��r��(e�����n5>��1Mr���N�(}!��G���?Jg�+����LtR��J��D�XE`l�- 5.�vz��I5T����)c�����
d���7C��J�z������fl+z+'n�f��r���nU�E�]�����W��q����u��)�WR�S;�!9�N!�W�	u�v�l����]'QcZ���q������4�MB��N�g0L +�e���7��w�Nn������&#���Gph8�%����b� �3�@�S�e�}-R�qX�7]�&(�(���bM���TY�������(�2�CD��u����!��s'��2��3���)�UV~5��j�J�!���x"��H�g:���=�DcO�'mE7�9�(����a�1�
��s�2�c��m$��Y&��
I�i�82�JD�
���Sm
�O���3De|E[.�Y���X�&��:!5f�IT��V���~
����9�z&K��>��#U���I���Ki��i��8������H,��&��*��3A	F�FD�/�s�2�i��"P���jV70� 4�zo���,�#�@�O������Rp��
�`�=����rO�d�Q������T2��'���~��L!%�����I�g���m���Ib>`��v�O��
�{�,%{.�N^&beMJ~)��V���U�<!������[��P����������Udb�BJ3�f��L����|O��Z��2K���}bZ\��YIvT���_DvA���O�7�����k?�>�����Mv�K�C�7���wg�g1E|t����p-�����_��������=:���Z:�����8q�[�),��	7i�L�@V;���t?m�'���xZ�E��f��y�%)��K��D��p>%ML=x��F�����z�PB��������N�!�03���w�'��
�0����P��@���`�`��V�����b^��5��rL��6
%e��6�������=)[��	6��ow.�/pH�_Z�����;J{���.����(s�>*�;���-�yLL1T(.�*3L�i\)%b5�TzhX�*�����T�MnE?T�|4:��b�A��x�����&�o�*t1�����7S����V��w��X��_\~���*��`�y�d0(����&�9=3)zm��9�������%��tw�6vq�� �hOK:Y1�$w[�-�=Q/�@H2�zS�B�w����{�;�����;�X;G?w������19|�Z�w3�<_)�`��Mg�/����Q�,�$�|�~'����%��j�����Sd�����	$�\*$�L$$��v���<���t�/{�_��s�q�~"���6������#Z�6�KN���KU��%*6���L�x��d =wI�G�����[�p�);�6��:�����I��yn�MPP��^FxI�B���0��|}��[�f�Y��E�T
aF5*@V(���c@����kY�IjP����r���������`��r7����n���}�<v//'�%U�agSt�R���r����bl�}Z���y]��Y����g����z����=�]�Ut\w���z�y�@jX�������w�����E�5���[�N��B��$~���OT��������wZf����x2�h�_��(+�&?��X�.�b�y:G���)b�c�R�5:�Ir��i�{��.�����C��ZU����yL&�f��!%��
�����{�)8����G}�#��c"y�0�a��0&�A�d����/;���K��W��T��!|1��m���qc������9��e):w�jV�`����@-��7N+�h���8�V�'����pR^&���^d��a��
��7L�i��H����+������i�W��TZc[+��ZtQ]������o)
�Q<�{o�����$��
R�P�K��!��X����3���D�f��A�|"�����X��^$x���t'����e�bzS�e�|��������E���
���N�uO�nI��{	�����9(����\�06�%��r�n�!�oB�����r���1���M���!�'��b�s���z.�	�S� -Pi�4(�������!p����;�F/�������;G'd���P-�:
%�?I'���/$W�_!?)�_��G|��p������IY�j��������<2� ��N�K�y*~8������,�����*aRl^������8�%G�����U�__]J�K)x.�0�?J�zl/��o��|q����lA	����������G��}
e��HGI}��-/
�ud��u<(X������"K����_���;�~�|
��U�>����������A���W�������9(���M���������������B�<����������� ��)!&��� E=h_8)i�R�A��I�r�N@FR�����zRt������#)Q��;:�%E�@�.�b������1��A
sK)ek#�p|s��]d����� ��L�X�2��z���o.�����=�H��=�H��=�H��=����{$�{TN�J�I��wb��T�C����.J�%�)
��o~������tR��)ZR��):R��)!�����~�77%c�;oE@yH>�C�D����w���}�{�0����wob�CT���R����H@0F��w��0��l�Cs,���b%�������uO1���Gu:�:����"v���t(����3��`��2�A���IZ���j���G9(�O��n�nq@8�uT8�<�3�1*������u�+U�����GHWp�-���Ba�Ra�	��_j��g~!&�(��B���e�]�����P7�-�2i��#,���p��Yg[
����������Z��n��P�	'�LF3z&C���������j��)q�x���<�������7���2\����u}<���i��������c_8�~���6�}k�X��F��B��9������_� 5���Y� ����}�T����{���9������p���7{���;�?�/���
��z�
��VV������E������8�G�m�2r[B�_[��k�������m��!����5�-�_��G_�9&��W+�"�����S^��V��j
�NZv����(��X��\����jPf�a��-Np���}�e!)�Qy�L#P!��:�~%
������o�$����!n��-��������Z��������_����D�;��2�h'@�%�6�Z�`D��5�z�W�z�X�N���#�N2{��dEt�+��{��(S%kUi/����f��j���6�J�$�|��j�����+������mZ���������l�84c���
���
���e7�6p����f��
�|��>��h����'��
�4��'��`<��g��q|q��S�J��v:����9�%�����&�4�X�)Ym4v���|+*��h��L'���W+��H��u�yK	����"�W)��$��;<�z���l���W���m�i9�zss{��m�X�(�s-�v�jT7���h+�'Pg�O�]y�������
�D����h<}�N��d<���D���*�x��Dx�����w~m��6wp9:�������R�}�����n���G����s=��1��;�
�d��������zS����[�I����\
i5r�����������8�������� .	���+���(��(��oJ���{C��V�4C	t��+
������$wH�Z�J�>�C����C;5>V~u�������K���*��Ya��$w�P�Q���:v��:��Vc#�����t�p16����M��*m�B���w�~{������v#OE��55��t�:)�J�)L���*���������d<_����PCex���F��������j4�Z0%�	���
[
��Xm��#N����d�,�fm��in��F{�n����z������Q����CE�RtR��$p�b�!(���1P��;�F�E\�0iv���9>��~-pqQ�
���n-��t���cl���}�\��"R�F�\o��~���C���y5N�t,�������r�����!�5�g�t��)I:Rpe�~"J����
��L7�@5��������@����~|�n8���Q4`��`��f����u��1wf����w���s����&Xi��z7��A���RB1��D�c\vM[�[@Y����tB�dS%'���%�
�@�����V��Z���KH���Y��e��Jx+�-t=�����|U-]����Z������J:�b�U�p�Z]�i7�m������~;�E���4���e���F;�\��H����:Q$�����Vd��c-I��/�����ZU��<�?��V�}&
yN�/����!/�]��c�=���.-������l�YR����)�B}��FF�O#�*Vr�^"�+�RXg�X��V%� ��Y�I�`Rg�d-�Tv-����Rpz����L����6�M3�$^K��i�VRi�g)����8���C�S��\�;O�dI����4���~���iZw���vV�m7�(�� v@�Bha���pP�	��jc���U���E�T\�6��?�{��n�B�8)����%S,�d���*Ni��i��
�y�K��hDx|:t����d%apto��+��J%��5�e����/�\�A1�VA'RMR=Of4����R��R��,G��i�\L�W�@��J�mVC8C���!;n�Up���C�9���5��
�B-�V�@���SX�`�����N�6W���������pS�q��o"c�#v?mC$U:
�����F��JO*�U�zx��;��������T�p�f��E�oP��veX
WNs���^�D����z_w�����(��5G����sT�{s~s��w��=#���S�0�FC����a�d��5a<�<-�-G�&���!�h\�B[��fdL�8��(
�u�V���^��]3��9p�6�j��B��m,�X�MOAF9�SR(�y�E�O��Nz��n0d�'D�A4�[7������7�J<%v��;!HvK����d�r��&Y'�f�0�:����h���K>e(L4�*��P���]a��s��4l�!Sw2r&�d8�����G7Ur������G�VO!~[%��s���Q&s,��?�AH������~|+~U���P��#�U$��q�9#��?R�|ug�a���Y^����l�����Z���Xp]L)!�Gv[T��<~W
)�"��k	�*�R���o�M�Z��[yB�����5s{$V��G��\�Aa�o{(�Oa���1�P��I6<*u�\�P���
`-�Nb�3��pm�$[�`�(��`V�]6�Uf�
��wF���J��"��9����S�'��T�d�	;F1��k��������`����L��&�kX�{R3��������<�fp�c2���r��q'���KYlk��ml���b4���*��xf������Ek�&�d�w�8������O���i�&YK��j%�\
V+���z�,U
���������C���!�pi��������������%<�Jx9�rGS�a�"����:��Y�C��4�[�k����f����5���r����}��
���P+�t#(�f����x�C����uF��5��������������jV���jN�knOx���%^�t�_�t��
���k�������7�}�[<�%��3�����7�TQ]�!>o2�a������
��7��4nm)�����Q����jUq^D��zzV��v3=��*�-T|}�����]: ��MZ�f)(����f��%Z�$WH36��2�iW�N�+W`�j�,���c#32��J�b8O(���V=�����6��3���(���!?
�Y1��HU�_��2�q0��"25�,�C���b����*
��{����"�����4Rs ��JpPo�J�FERk�[U��o�	U*����\����sp��s��d�+������$)��������G��PVS�v���l@OuP1J�������X����hy�G��m#*��$���_�c9bLz\��g�a�80�g^����R��Q�w�
[uv���x	���Vp'S��3�T��9�T~0��T�S!�
�Mn�=&���S��
	*T*�=�O������N9o�L�$�*a��L�l��@��?BWIf�Ub-zx����)m�����C�4�
|~6b�.Ce��SOV��/�^��{�x����d8���O�K�����t�k�2]$~B(��H�\�KR��'9(N��C!�+���4�;Srm���f| K��0��{f�K�l�1�H�\����	�ikO1uy^�LT�D�Ch[���Vs��Y$����
%�fL�#9�
0���j�x�����/�����F��1��)�i���q_��6	�X���mm4��z[�-4*Y�Z�Y��fI,�r��kWW�[�)��N�6��T`$7�1H��^_��e�,�������A�4L9����h'R�D���x����s|�R�@=�z��%u]]�����!M��i�,�E����b��X���Y�w'/����H�s��������h�2CK���
>s�|<��{��d#.u��3�N�O��\�s(��8��L?Y������\�V8;�cHr���l$Ag����*MVb���H���m��\+:JZ�FI�!k���7{��^>${i������^��g6�&[L�/�3+��l*�P�����w^
�e�@���Q������m�.�z����\;g��o�"do"��p@�F�,\�q�L�)�je�����!c��e�����o��a�4��F����Rn���������	��}�,��Vl?I )CL��h�1���t���:�^%��F��������\�s�C�F9c������d=�%i5��1Rgbj����O�#P��s���/����S����p����sv
�9
s���yo+�k�wC���J5*��R2�P0�[���2y�M&��)]&~�b���p��lg�x�Hb-lhH�
"������`b����z�?����
a��4����o��Cz��������&q���Z��e�UC��V��\�-�h��?�D���|�RD��B�$���f
Z�?����k�bO�(7s����-OE��{%�Sv�L���W?w&G�~��sHI�%s��o��$�d��&�d!���������j0��B������Y��S~��>��Zw�GEsn*2h��`�M��xX�Zg�P�2�J��D!-M�KED�:�o=RD�;M3T
������wEdf<�3���go����S�/|���Y+�����5\��Z7��i�o�ud����������| ?T�q����d�
�|@j�����x)g5��p0����l�*�g@U��O��l����it�J3
%�	8������v�c�W� ��i*URY������kp��T��-s��0�E*A��O9
�<�lW��E��2�J,1:l ��&/N��U�yx�a�g����0�i�/�����5H����OoK�X����Le��0�r�2g_nv��*������xW��R��KwwI-���^o2��F��$b��q	���.�P7�Pp1^zY,T%u��6Q����xN*��cZ�/4����V�V!!�����
��������tv�58���p�/�7�n���-�M��}���n�t	w���n
���������O�%IzZ>x��O^��e�Amd/\vggJ;O�����d��} s�n�*~)m��US������]������Q�z�w��sU|w�����y�by�b�HXc�����7��b�	��E���'}^>���;:�;��D�����@��H!+��N.&s��Q
��
]k\X�J���!�����!v<�,�Y^���W��V����c)�8$����������&����c\K<�j�+���:�&ow����Xd�����C�������J������v�,�Q����XBzg}��Z{*��_v��u�M�ql�Z��u�e
���>�Z��R���TH?������	�"��W{�y��n�����Ra7�����6h��i���	F��h��O��;(%��������a��BdC&�f+cEPZ@�d�0}b��������l�X�,��gK���pB)��\k4�r���&������K"�7���Q����w&�v%gE;GEx��V7_���w(�?J9xO����4���4������e�A�b:Q`�*��vM���a�f�-���/��{��������M������+����$��xy��=��W�ov��S��Gc�\C`����&�%��J��@&�6C&#pF��I#��a��Eue2��q$�e��/q3�H!��_bU������	���eE�������E�`�������>{m_����`�k� ��5k"��neU�`�Q��
U�17��8-��T=���&��u�4g�'��e�	���K7fW��L�op
E*�� �f�-�<z	�"v������
�~��`��{�Qo��`�����9��v=y�X��I����(
�$r|_QFcyC��Cg��K���d<�^����^�_�J=�-�,����@���k9a��yPk���/��-UW����]��w���)�8F5��u����w'�����o;G�U����W{'{������;�k�����Z��el�c0'|�!��
7O���@��y����Y���
K{�q(:�@gw^�����M�@���Z�f/�F���+��.W�������d��mN$�R�������('��%�2XA�z�.���*��o�	~��H��������)��Uq�:��1J$�x������T�����%�zwx�9.���/w�w����-1��7{'��(��DT��gL"%�Y�LA��u�;���s����3vkp1p���{w��%��d����V��,J����Y������S�Z[[c��(��7��\�o
\����$���0��z���AiuB��.�$2�?����2i�*���71��
TX>EA��UHk�K�qr?�p� -�mVK�M�B$>nXm>���ER-\>�������[��C�A2g�0f �8
_+4�uF��1�8�l��Pp�xxJ�����A�*��_e�=S{���6���
(���(��o�rx�����iR��U!i����W'�02q{�I�-����d�;������o;�z-����U���-tN�6P��e��G~==��r~���*	
�N�p5�>��lV�O��(���/wpx�O������o���$|��q�[���I��F��$s�z�r9B�J%���{���;���n��El�L@�N�f"�x2�>p�@%�����Y���q(=�G�W��ID���/�<���
5��)nx��t&�I�S=��-/��0�������k*_YFZt�H����EXQ��8��)���p����-���8R)#��h`��Z\��x&5��A����t�9>9��;8�"�`�y�S���Be{���H�hK�&�`�[�Kk�N�|@��~(�+hB������w���f�I����L^����*���*;;�"n~A��"��������U�X#���������J�`!������;��8�nM�DV����?�zu��{�Tr�:3�e�m������-&�}��y)��?u�:RO;9W.����CVuH��*�����������~w@���O���_aC-�L���{A&��<���Vwv&�%e�����q�����8���,�LUp���.S+G~�3C
�?<2ip�Wus�
��������I�W3�����p�A����R��n�)�'jPV��O������J������C�y����rIy0��@�!WL��@���?�I��]7����6z��������������98'��#��\�?7��jT����6r<M�k�2>^�a���GW�g���GM\�:]g���Wf�O��j�9���_=���`�
�`f��'���������r���Te@2V0#��'���:�X�n��Yod��Se<����y�]�*��������"�
�6�|@��:"�6�,7��/2�`iM���E�&|.�N�f�s�%�nf�)��1���+����^u~#�70�����r0�3�
����@u�=��^�Q�q|q�3��-4����v6S��6YY���vv}�_R���~]Y�5�����jW����D�~VP�(��1��3d�x�A�}'+U;"����������/O�
��S`��e����9�p6�:vN��>�hg�N��
��2��u%���W.�r��0�(�B��{����xB~�}�M�����t<�h�2�l3�9+���=[�������k�����R������7n�zs�,3��0�q��v@��������7�\`����{����7��:�������F��\�o.�7��]�o��7���`�u�q:��"N0���f���XYH
�+%��������ne���#��ko�0_��4�,{�����Vj	��)��I��J*���t���w�(������[_'+��"A�.,��?��}�����3�hjj�J��5o-��V�k��V�T(!������L-_%��#::=�Q)\_������#��t��b��ez}�i9����[r�vZ�����fR��KTH�5-2����h%�TKEh*o!�5[J\��/�](��o��,����'���=�h<#���Bn�8�b�iH�vi��D��{�3�gI���U�
xd6�0��Rj$�����-�Z�JTQ�]hJ/�
��3�"�v^�:�mS�E�8Z��
rz���$�j�����`O�l&�L�*�F��5�?R:Y_���R-t��y����B��Ed�~�Z\�=���j������u�fl91�7	��M?Go��$���U;�:$���������U1i���}PR�1��(��(v!P�b�a�C1����2<8y���X:<2a���F����uo��J���i�%��q�4�*�%�`�)a��������*Do��^+��}|:t���(���?��5�Y�^"�h����jdc�2��'o4",�{���]2�������1��U���R��
$<�,P�p����c����j3[1���<�$��B`TaFX :�a��	Z�����`u+PqK����Zt@��tP��U�U���nbmfa` �Q��e$7������#���Q�K�d�h��C����,1)
��XZ�0j���1� �W���j����f�E�y|)��2,�k�N-��J�����D[�K#r�[����0�����n��y���Y���������^�E���c'����Z<;��r������=��i�$��h�$*���f�����Z�����f+��n��j��n�<�a��5`V��U7o�X�
OCVa��R,��[G�\��.{Y��l+��,0;�����t �E�!"}�]!fOD�&����3�$�c5#P�NJ�Rq�u����y���V�|zQ�t"�U�`A��������aGX��	S���NF��������/%��P�)�0�t�-]�3�P2;:	�]����������������� �������8iXdTEJ��yw6���=���*J���-�{��_;)aJ����:LA!y7��=R���l'�U��}-Y�U*���
���X��|+�`�&_�fn��*�6	U��M(��nu�������
��8���T.�v�WD}�'?�5
tb����k$���@�F`YtT�R
�!�2�V���8��(@U������9 �
 ]���H��Ha���D���X�
����s��V�iT����'53�~qty��ci��'D��W�t�#���K[�k��{l���bl�V�j�{�
\j������ek�&tm�w�8�����!���6aI#�d-������R�A��zJa�����*��*�d���fpJ��5��P�;�������)�)�pq�e����s}
�_�d|
	����.g�(�`D`��Rvx�Q���M�$���nZ�J�U�
*���8��'��	�)����������YgyF�d�x����eT���k�e�%4N4y!��x���:��-�;�v����E�y��L/b#%�e��r�����&�AVE5���Yx#���3v�!��yX@ v�/�����^��
��3n������v�%N�E�(����=i(���V��E���������R��x�
�	93�!h��Li�
���T���k��r�8����v�Rw�^���&�]o�1O����J�b8O(���V=e8��cD0���(A�t?6
�Y1S�H]<���6�$q@���N2��,TIj���(���*J�z6t���n�w�������%�����I]b,		�D������5��*i�7��
�"�D\���sC�kd~�B�L�6����bP2���j9�=6F����*. �W�n�[��5|�	s���KpIe�/�,
V�H�f�|��l1��N�K�S��D`��3����;L	��3�����I4��*0�6t~��������e:����v3�%�P�\��Ri���U8p�U�.�U�e����-��C�������>����+�����*-9���-�$u�f��i	�$�{��n���o������L=�wWc�4+�W�S
8�����-.���
>�y�������D�0��D��4�
�Fb1����)���d?�_
��.~����B]-5/�p��=����
)��������H�$�#%r1t.Iips���@8)W����&���L]��-�siX�w�2��/�j��eX�T�X/�W�1�����I����Ovk��9��O�Q�T=L����lm57Z��B�*Z�X�j��9��@�
�5uF}g�������F��q�=lB�ncL[$7�6��FQN������F�]ok��g�%�Qk4kv��,�M�,����U��~J��z�e$0� )�k�H0���\��2�������&\�����7�;v#�z"u����1��o���;��YA�@�	������x����F#%R��}�6(Ngd�/.���$~���������;y�@��M��F���A���
��2l�_���+t����q�5��0d���g
������[�@6���+�Jv���>Fj���(� �hI��|���h�
���X��L�VK�CI���P\���E�N����U�Z����~~���~�(�7�k?���3NS,(���Ac8cJ`\����2�);��,��\Pv
h�4x9��sN����y�e��(�L�A���%����3P���V����}RZ�_����
��6���N��i4�-k)��������rm�t�&D_5K�T/�HCJc��7�u��)�_�����^������o���=1v�S�����8��m��F�9Y��FQZM�w�����z���S�	.�:��K�������)��*>��C�}��,rqh�������Di�b�J ����s������P�}JBJ���p�5��Ed[c��FoacC�����d��c��f���Q�D�T0�L������}�<��>���n�i���6�u����Zv�,#��������A��F�|�&�������#{�!�$���-�T�$� ~
^���5�1u���}��.WM�m�|%�Sv����S��e�9i�%z��I"&�t�s~���e�X����������������}W�
���L<8����D��3q����{�4�''�2^&��(e�Lw�&;pSM7�`����kz������!'��*A���*����7�{;R�	"�*��}�ki�h�����E^�-�se�e��@�^p�	<������&�cw	�V�Jl�@��fJ�Pe8�B?2���
7ssB����`��V�2����
�R�Q��@V�>>-�n����-\Z0�(��B��G'�#*�Y�9�I���$��tI��F�������yR�2�U�*����U!�<�r*���/
��<G�If���Y�
��D4>)M^�~��6�d�,pT��c�b�m����_R��Q;�@���*�� 5eap��5��M������<�}��!���vo2�^%�wH�b<.��%��7�z���z:]����qC�%�K���R��R�����T��I'�D��On�	A��J�q5v���o/[�[��0����7��v�F����I�..H�v9���7�=�|�O&�%�G|��w�����K��%]��+#���S
�d	�7Z������~�^��v����R�z���~|��������>M�Q��j���.*�?��;���K.���|�ng������\PxTl���E�~?����y��s���`��G�#�V"x^�?��RN&6�:��+�C��4�������T4�Dqj9<c��lE8��O�����~Z��r�Z4�X�Z&M�/OB��0���j��z�k��V:!"ow����Xd�����D�\��P�J������v�,�Q.�4%�I�A�}������_v��u�
�
L++�j�b����F��~��d�A1	:H9��34%C�K�H�l��V��S����w���S�!��?'kO2�bUu
�n�s=���JR+��hv�Rk��*������>�?���m2V��w&�v%oM;OMx��Z7g�W�{&0�?Jy�O��G��Wk~��W�����O�eY����.X���l���#'2X�(�bT9���`��*��>xtls{�)� %~|��?�+��t/�:�'����������9%�|4����Jt��Oj����D�h��3���4js��m#����i���� wz��BG�8w:Z�|�\W�v�EY�EL2��T|����B����QHe�b Gu_�QsWWa6�l�DhI�������,����nrrZ"%�~�Q'N�=��i
��O@���?`��<����3����Q���������8�/x/�������7���;��7��G=[��E�Bn�JN@��$�J`�&��:f3�4(���}E��������.�3���lz=����z�����N��s�+���\l I��>O��)3i�Ih���'���n	plH�f��{�$��-�2I����t�m�����]�������K;�p��lR���^�6$.��#�?����0�|���Y��_w���Jm�ND]L���/N^��������Y98yu���N^�k��~%b��������C���BUz�5CL����
����
��/�d�3|�T$sY�p
�'<���qv
�x>~�z1)��?�\�L+�f���d	�S9@��W)Tz���	����H�PV�EW�$DJY�jFy��{v�l�����'�u(��Y.|���BX:�?��/"����"*����Pp^C�������_�����@������3r�?�Mi�����(�@bs�D"�.
��,��Rd3�G'g/�RyZ�������v�^p9�V!�`���]gD�|tf���bFV�3�c�*���B�+��
8 ���
t]�M�Kj��$�HT�#5:�H��Pio�)�B"�Y4���3���?m,6c5���l5w��hP_#�ad�,�.���NKP�����Kr*�Qu�dsF�Z�ys��hb�!����.�y�6�r4�4a6Sk���M0i�|���oS�$o}�L-�/n��6�������7P�����DW^���6��Y��O�D���+���tcT�2��������2k��]%t�Jut���������-���r���F>�(�w������8aU'KZ>��c�fx�P�������e1�R�/b0C�������R��%���5�O>�&�^n��]���H�Wc��:I�h~�.��p�>"�0�9��RI�yb Y�bQ�?D����B7��Z��� &B���A%#�H�e(n��C5���Kl�9� }H���N�WfIf�-�Z�9��b=l�*2M��2�+K���������
V3�
��m6c{����J�H����UR��m�`KzX6�!��w	nT�d$�l����u.������7r�2An�+:@Z����~�U_���6��E��7I���G40-��n�t���Kj��W������=0�'64�.�W����������tB
�����������ay ������G9t�wg���[f����I���$��(>m#�2H�F)��_�v-��t���pj�|�us #�s�����>�_��)�}�=�
e�rf_9���[���\*�=���r�,/q�c�
\���#����*kN�^.��3&��&?+����=��@R|�r��:���	����|��_0�2^�����	?UU%���	;�E�w�.|�!������ifm+i�g�Y�B�P�q���� �
�V+�>A%R6�#g��wB����)�MH�j���%wvmc9CMW����5����7����Sg*��*k�@n%��]h�Bqx3��Ll�>���J���
�*qix�5�P�pY��������K�3����c��V98[#'GG�f��U��Sm~��2}O��Dr��IS�9��$n�A�X�w���F�0Tg<������
9����6?@w.*+���c��(tK���c�(=���"�ku�#U�#�
��r���1���He�"=>�N����[k����T'���A(�9-�uar��LEDC�P����
�$��.�6��4Z�?C+7��8p^�\�/��������tQ._\���!*
[V�����N�b�������Z��f����}�Vs��T��2����
����R��1��V<R��(XMD'0�0z�8�$�{[���(�!�`�|����G%��9��8�
��X�����z���.L����hJ��5�Y���?��K�������(�8�Z_m<	��pT-��	�j�xV}s(�<���t����&5�3�-Lz�����oT����������~C�u
<��� �KE��Q�jk�P��{�i��4U�����N��A���b�7��tm#'�3�Bw1�x:�{�:���M���j���
���*�G�E�A��7�?_-��Q��NJ�!	�zJJd��&����o]�^y�mq�t�Y+us~]����P����W�c��������E��B������t������jT��lU�=�
�
e�e��������l����@'$h�>���)" F��U��Y���T`��p����j�M94dC��M���,�x�q������$�J� c�(@a��`��^��������-e�^
��uLN�`J���
R�k���
w������j�$%����*:B�����d@�uiU'��):����%%��?��O�_�����.�����G 

�����K����b�U��2�8�����LG��TM����V�kj2���i���|uk����S�z`5=0C��&\M���W��hj����iC��N�������L5�j�pM]���5]@S��6dM
��d1_x��=s�7Y�q(�B�XM�=F��v��V�~�Z��1���������>�&:����=��gs���0�����at�0�z�3����o���ya,���M����&tUK/f}�V9��3�����rq��EY4(���5��������G�m� ����VK�"T�'�l��|$���w!s:)Q[U~�r:�&�V$-I"���Z�D�U�P���9Q}��<D6����2�<�H�t{��{b�3I�%�X�(�7���Q.4|�j�����y*�;�1���`bQ=}*
��='��=��p�U������0��6�W'����{���7�����  ������P
%;�%1���#����'�I��-{�9��={���B�Jw����g�l�U�hd#��J�Pl��J��.s�j�E+�j4$p�u�	���K-TR��L%�20�/	��	�-���NG/�TM�C�X*�p�@/��-��C�$�Hj��D(������K���=H�-�f�a�"$T5sR_����w$
!�3%f�L��dM�
J#���H�k�PD��!�r������ ��R<~�'	�
�&��P$d;���za<�����xOE����X^e�"�R���m��$�D��Q�,���u*�\J���#z�Y���ec�h�����*���������"E���@��:z���*��8F������yGj�#?4�&iE:5�U�$��,EfS������,T�|(&���[e�:�+��h�F����>��f��d0Y�>�)P��~��(M���>v�P-II:R�I]�qZ1��0��l��(����x��x�y�a���:����w����zx���>��o��U�%�I�Qi]'[��:GGV=���7G��(�-n�`X�����r�E�����{O�\p�������L��	W��2��OU��U�� N=�x�
��,���V�-D� v2���������W�����)��".'g��3��q�'�2x$�T�F����|�DC�j���|����/Q_�A<��;g��QMD����]�������w��I�R����{~�9%����T���9^��j�Ih�YsZ����$�E�P��,����0!���E><��9T����I9��l
�P���z�Q@����q>+l=��=�����/��t�����6xv������Q��@H���A!
9y����g}z�t
����
��I���~��7�(�
���5U��2�b�������b#(�{���L���h`6��Gh��h�b���"�Kc 2��
D�{)]I�)~�#�2N�(�	 U=�S���H9�T���44��:	�=�k��eV����0�^�G�<<��vVS75���&c���a�v�H��6�OL����d #ga{>��O�J���y�N$��c������;R8��=1���|A�����oi�%�h���u��^�����bz��
�Vs�����@=)���:_$�L!��"�D�*��������6���PzvM>a�{������r)��a�����\�'�%�����IV!�a�M��@Le!�lc��y*P4�������i]��+��Gj5^meV,^aW5�w<W�R�o0G*��+��@��J��dH41���!�������#w��M��G?M����t�*&�
�s)"�R�"���"w�EQad�,e��_��x|����S�9��`��'q���d�pn	��'n#��xV�����R��J!��D���v����7��J���E�Y���(�&�n�_�L���w�.C�;l8��g��t�,�@F�H��+��*K����G���R�����%�y?��k��1��%��
�^���z:"(�e(i�8��6���
*/��7������vNp&*�]����[����S���������w
qW#���0.����m�'������(��&��0�����a��E�iJ�1�_2�D� ,���j��%�Us���p�S	�����xP��9P���::���;O:;��a��mu:���d2N��,�e��;�������^ �h�_�{�K��^�����w�H��H�������!�)W*(�	
G/)
���������2;�E���{�=���<��??�`59'K����Lrtd���6�:��&d<6�g���6�:�������y�f��
sn���:
/CW<����
k���5`�4MM0����X�2����%
^�]g:��g��p9����?;�!F�u�A�`��V�����;�B����e���ak0jo
���;l9�"��)���U��B��?R��������LA8�GDO�������%s�tm{�|�t2E����,��������������S�q��|��~��
�7�{0,~�z����K�
�?9*W��}���TO��@{ �_%Y1�����+�z������`�NG��*�ty,/T��eu�-��������*�P�X���'X����R��1�
���Ha`?;���'M@�x�?/���A�lL�u
O'�}e���H���3Bt
%�X���s����l4:r����dY-]H�=Z�$��yJ���;����0I>t���������>����c��;�l�Dp�+�eSw�	���.#�,�8�OW�Q�I��",�����0�4�����L���!�=���|X�� ~��/��c4�k���cR����/�Goiz �������rH2�P�E����_%.��� l�����`�q�z*��F������U��p�)1���A?����3��)�XS�$�5��n�B;�l8]�.�4�Q��p���R$8�M�<arM���L��g�����������|�F���?I�^�_L���_�����������������M������`9/'�Qk��
��c�s�Q��diQ��:�����}i����sw����W���d��
�m���l29_��g�zn����s���?v�����Fo�;���d���a�=_Bq�P��>mY����`>�I^F������/� �B�� �����x�B��}u�:�0�9�j*�E		�����6D��tN��{:�����0L<Z�����n�=�:���������U��C9
r>��E�Z=�&� �(�1���'�#���J���Gh�S`C�������c�>�/zkb
0002-JSON_TABLE.patch.gzapplication/gzip; name=0002-JSON_TABLE.patch.gzDownload
#16Pavel Stehule
pavel.stehule@gmail.com
In reply to: Nikita Glukhov (#15)
Re: SQL/JSON: JSON_TABLE

Hi

so 29. 6. 2019 v 7:26 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

Attached 36th version of patches rebased onto jsonpath v36.

I cannot to apply these patches on master. Please, can you check these
patches?

Regards

Pavel

Show quoted text

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#17Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Pavel Stehule (#16)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 29.06.2019 8:40, Pavel Stehule wrote:

Hi

so 29. 6. 2019 v 7:26 odesílatel Nikita Glukhov
<n.gluhov@postgrespro.ru <mailto:n.gluhov@postgrespro.ru>> napsal:

Attached 36th version of patches rebased onto jsonpath v36.

I cannot to apply these patches on master. Please, can you check these
patches?

Attached 37th version of patches rebased onto current master.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQLJSON-functions-v37.patch.gzapplication/gzip; name=0001-SQLJSON-functions-v37.patch.gzDownload
���-]0001-SQLJSON-functions-v37.patch�=kw�����_���[?�$�v7�+��q_�������HHbL���������HZ�}��'�I3�7C=w���nO�:Z�
���@U�!Ut��������:��St���-2aQ���:����j)�s@sL��;���g3�[��dd5fW���.��n��I�'��cr�Qz���,��������T[�V�2	f������Oo�~!J��;���-��K��c�>��.��o���N>A�J�T��a��13�l�jP�W�qX�>��W�L�u����t�<�
4�v��������tC�������#D^�^�W�w�Y�YL=���[1��r54�oBH�O�	H)��\h��������B������5=�[��&���M���rP�Q��Yz����hzk����kx��,hF��A�#���?:n����T��n�^X>s����qX�I�2��i���/�������������3����e��	!��6�V��5�QX��������q���O1�>/�TCR@����r��"�]F�R���p�v�3�/�m����=����rA����a65������������KW�u��7�K�����?S�6Mp�,���N��2���vr�j�I����]0�����;��`C�(d�Iu�������
AE4�
k�#�����b��]4���+i�m�.�hVd������}��U�D��&<�o�L�d�h����,�b�8��*����
��Z��6|Ii+���i�j��A����d�.Ot����ks�\WN��{Ev�\W����\cw	�fX��,�*aN����2�7��H�a.��/�4$dR���T:�(
�����2�QL
J ����Y��,�	������w.T�lP+ y�+�iH7�3���*�;hEv���{�`�_@2��,��y�-�T�[�f�������H�/�BHtp�%|��(���T�����X����@��Ph���U�=�T��Ns��\��&T�p��p��K ���%�{���
�~�}t`�����vmp�uR�4dX���F�
�a"h�9A�	%�`�'����[���l�$L��A:+����A���P���M+��Am��z�2��.���O�n�-"������z�H������l	$�*5Mf���d:L�9���s&n�"�l<IC~6c[��6b.�L�z
��2_,�u�~�J�����s��\QE��#����So�IKm�@��N�rA���,CKpl���d��x����m�,��3����t6�8'�,!�]27L�mI��k���:3,�h^�9��CxJtf2��~X!��}FV�,@i� ��!$?>L�>{������#h��v��=4	T�������'��kQo�+D����h�3b����]�WA.Vw����J��#u�;h����M����jf2\;8���$G�8��Ba���~Nqm4�v�����G���`��+D�����������~���e����jA3�_���'��9��D7\0g�.��v��X������ 
�v������n�%f;~��W�{�q�h�c�v��k���x,���j� \�_����e�j~0�P��`+6��������U�MOKy�<�5\���y(heX����vm�l�C�!H���gOx.�����R�R��O�����~�.�����A����?[�etBD��O��f�0���<*������0A&��)�dK����P_�mE����%������4[������������T��Y�@�P�!c��_��~�2?p-,O��\�7C}q@�c�9� {(�X����2:�`^�B6c���0/���Ec�L3�i�n4�KX>�ck���{4�iB�%���B�hI��5�h�O�m�$f�>.}�&����(HC6�M �`<���P�B��)�e�������!��bx,%�8�]B�9����Qmy��`C(Y��(�d�_2��� ��ng@Y��h�zCL��|��4����1���r�Ne�9
���\�S�D���GeA�����K����i��<���"��1

Dn�!�E> Xoi?��@67\x�[��s�?lV�o�99@r�Sy���}������//�.n�g���C��.�����Q���v|suz)�00).����L�2|��rt>M�H(1no"~/�1h+\��*��vlh��J({���E���m4��&	��J���+�K��6"�
�|�],�4D���P�a�>���H��'�`^#{�����j"�x�&���F��A��Q_���L;NI ����4H��y�����J�=����\*���
��@��������r|vK`�
0�B���3�]:��/�5����A���������pux��RS���E�?#�8w}�24���Y'-�S���QSt�`FM�~H���j��4 ������2j�7�lw�iF4|=1h5=hu�A�-��O<*2��q�[��2L31.���G�l1����J�D}����d,K����i{/'���6�6���I����! �_����|��n���n0��K����U��������O}
��Z_A���`# ������Fx��%���8���l47����1#����K['�����=/|1���/���a�k2cn8�N��GF�O������O�
�|�a�N���4j�H.�3V%�x�J�=��/�s�����H����gCF� ��8L����
��.��E �P]��O�D#����g��)�9����3�����&��5�����%��.�$$�$������8�KA��8��G�6�D[-k����`��iP����d�N]:����;�?d��oPb�K�/j�i0,�}��+EV������"kz�.aD��
rn��E��������Q�����Y���&8���p��;b�o��Efq��I��0Mv2�@���l��J��B�dI=ad�`h4)!|�|���4�#��� ����#�$��c���.���y�B
35c	;���!�1�s�&pq���j��=H�4?�iF-&}L���t�5$tR_��Z���st
�h�V3�jh ��%�%KA.���E���)�����,�������T�k���;�%���}�����.�3����=��������T��7����(N���*L*T�P���m�y����H��{����^Mm��������<2SFt[>o����3��|q����8
�� W��(��mOm)�����A���[p������v�;W{b�"����1Ju�A��mX��������Dt�\��Tc��,A�FY��x�z�W��2�8�E#>�&E=n�PG�����]=�f�~�E�����I	���VL^���BG�ck.�\��B�����K`����lu�������y"O����.]�^���C���8d������{��!A����,1����%�������1d�p/����y"�3hZHD_��j`-	�F��1+=b���AR�I�H7=*wF����w�����s�`e�q���

y���C�=
�������B.�	�B��� ����b;�3���J`��%�.�v�3&X�`;pC��'��,P
=DY�f��tIL2h��6jJ�(V7���H�!+��^{a���B�����q���E��H$	@���v��'��jk���DU����.N)�����VZ�O����*/��p�������?�<��V�[�h��+^��p���2aJj<a�`\#.�J�s�2�������bYI�mL��I����5J�c��C��ixI�/�v'���J0�SC'h�}��+j����} ���M-[(�r��%��
\�=��+k�:A������&3u2N^#������^���X����H����vL}����<�flI�
�c��P�`Kf:������5�
��!�����_�Tdd7M&�8�Y�S��D|��QI�Q��;����^Xk�����\c�N��4��,��Q3l���x4'q�������kF��T�4�"�����"��U����� ����rS-�8�W$�g0%�Uw!�#+'N����AT\�)�	��A&���!�!t�%Gv�<h�:�+��� �a��+��7��J�P��0�!��0
xa�q���m��&L,�RSO1�2b@����ZBO��`=(���(���x�(u�u���6����0�}S�F���h�����F�0��j�c>d�vZi��'J���U�"f���n������N�i����^S7|��[�&����(�R�J[*b�Q���Qb-�x�Z	���9%��T8^)���9=e�Z�.�7�JT�x�l.R1��n�5#xHF�m��h�'t�E�aWaE�;J�[�'C.q�CK�aL�u%W�����1$\�G�
j��$���:s����2@SS;E���h��3�����:L��j�:��,���������cC��K��K���MI)�h����^�!���Q\�zD|I��y�a7�1��]�<�z�.�����$�Y�-|7����Xr�<��t��|C-�Q�U��>_���$����==��E�a�o���z���{���]$����I�J#�HRY���������_.i ^b?
���=Q,�
NS���cM�4=�dd/���.@���-t����m��W����Q3z$7�D�X��lWO�f��p��V��NGF;���
�;���az��V��������| ��U��Jtyz������$�DZ!�����[r������/�������r|I&���
9����	b������Oo���
�__�����������c��f2 ?��O?^���?���RyF���pO1sb�;��o?�\M��JuS�'P� bc�A�5����v���g>dbG��YC�gx��o?���������f�����"�W�B���d�����E��Kd�K�n���."A^]"�S�d;�I�e��
�I�����"�KX��9�����F��O`8�
^�g��3x������w�z���`�9�oT��M���y�o����O
�e�~�8��^&��(��0����In��@�J�����#�3Y�[����e�3�����b�5�����,�C3A(�G�����/� n\���;X���+���$����/�������Gv�[���{���v`��T+�x�r�_��52|�R������=�#,�uX��5��s�E����<�U��^X��������W!�-�%{�?�o,�������0}��ru�+l�f[B;�3���Qm�r[��7r��c��Z��2��1p�#���.�.��3j���yn�<����X�g�'����O|�����������bxK�-��D���$1\��]X���,j$�~�6�%{�&]��xM]��1�c|�Xm����W'r���(�9�C5��)i�����JO2���l/�f�3�x���0yK�h}��4���=Q<^�c�����e�8/>���$�)���A�x�D|p~���0y(��F�G9_X
��$���$D��3���x�I�[~�o�A'yLK�T����T�P���$z�A���$��Ua/�����	���F2��M���g�L>�sV=|Qb1�_�r���31m�;����L����+w������P7I�7L;v(�~'Y@��<�$<
HunX�	E���#�"~�p%���������`;%M�:��h�L���0����^�jh����W�-�G0w�d�?�E��z������C�Gx��������q$����b���AB�]��s��mmt[��x�yx�$l�m%����u����$g�w��������������RW��-v������x���^f�
2�Z�+�Kz�?��^	,�oIKks-���%�\�+�Kz%�����^~+������V������o%s���Y~+�����7��S���Q�o8�_�?���L���&/?}-w�����~��u��H�n�o��Xt������-�[xy�/,Klt��2.�������m��\��x)����r��T�

����`�m���N<����	_:�=^��	���4�	�C��H}r�O��T����[$��(��=/���4��U�k�>�Ke�@���=����j�	���=�Cz���0�Efz��B��Z��C+���u�Et1"��^����U�O��}����(����a�z�o�����?���������"t�"=�&�Y%UT����e�^:�6�(,eT)5��|�Y�bG���s��$�����t����E����2�p�:�u��W��o��t��J����Nr:������F��]���Mm�*9���-�%g�R�X�U�JEl�������;Rra��_9XY�@rxA���8�QCP,U�[v�0ZTU�5Ha�Q��Z�t�*s^��U��H����m��������)9P(�+��5z�$u�?�����((�Mf�����0y0����Q���oF$nX�����05.�d�������k
����fiN�g�LpMR)�6$yM�t����e/hX������I�h�(�Z�t>�^�~Z
G�C��k� >�x�GzY��k���h�����e=xZ��N����[������p
L������{��8�i���=&S����������Kio4���7#���Ux�[��4�����=Vk(2�D���U~��+e�Y�R��\^VM	��u5��i���3�-��r������9���oL �tjSt�g���R�N���0�A%���>%"u�)>����������.%�uG[9���h�2�?��sc�M���n�9vY��M��6�N5��]���i��<��]��
E�Y&�X��Y��C5�`r+~��c����g���X^�������cEY@VW������D�k?[T)�j��x�-���=w�Wo��07$�s�m��9\{�^�gg'g�h�f�w.���3�5�G�uU����<����%������2i�8�T���ts�����Z]���n_���jH9PuYT�7������Q%B<�\Z/8T����h:m7{g���K�3����T�S�-�w������.f���i��@��E��^*�G��k�A��2jn��kN�����M:��uo�
-�u����w����� ��N�������;|f��o�u������R����w��<aOT~�>V)Hg��/�\�	U�)�Mu���i�)q�,��b�]K�mJ�QF8�X�y�d������������O-��)���^����k����<��n�,�e��(Y���{�������A����`�Y������fk�m}��V��MC�nq����Jj�`�,�
M�C
�6��9���{��3�P$��+����w�0�y��3����@ kc���l��X'�)"�� ��j�������A�R:y��C�S^�����z8����Bz���S�����i�� �d�{��M��uG���MV^N����?��M�%>i���?��_��B*���0(���_�����Hy����aeZ��o�{����J*R��.-)����B������%wY��,���ii0�u����q����sJ���iy�U�m�����V�����Y�=��������~O�9?}O	d�>?������[�2><�N�8C��ph��t�����������N���[}�y�^�P��y�����n5�����`�s

����k�����[�^���)���p|��1�(CTT������_G��������j^Q��B�r��/����t��p�8P|OY�ZO��V�:>e�Q4{��"gx�{K�s�6�'j�Y�j>FeP-u"\S��m�F�0���k��V�F�q��3������3�`����]Z[>��2�!	���:#Cu+bW}��y=�s�]U��1,�5l�u��8����?��������{vEx�3��9Ka����o1qAdB��O���&���2C���Y�u���n�o�Zg'' F5Z���a�����c�� -�&�N���|�\yC�!�EW�@�8��MV
*+l�,��j�q�[HQ�`r��������~21c�""[�
�@�fO<�0`�:6�`Ick���,�:y ��`#�@�u�c�1Y(e���LYm�g��w)ezCJ'��pt�~��f�uyA�v���5��h_�����W����*���'��
�1�D�sy�����j��p|������p3Z�&(i�FJ�m���eN��#�m�d�������4H������d�~�����h���R��a����a<��b��;����,��,���49���
��9�U��N=VN	����^��A�lZ�����4�k����rzU@��T�D<��j�����(����s=*��R��dP$r��������,Sl�����7*�����a�B��<�c��=�N�LGJ�3�����-��>��2�".��O���,�Y3�T����5��f�U9��z�G_3�����)�;�D=���z�]w)����ij�%R��f�Iu����D�$Q�s�P��&�6�!K7B����%&J��p��hv�W�4�bg��EK������:�Q�3KK���6��2�8��d(>�Y�F�p~sa^==���
����(�JA
�
����`��%��]Sx��Q)2y��,^D,<�P
���'��p��Z`~@4�"z�G
�j
.EX���~lZK�3�& 
��(����.��*��(xh�{�w���M���2*k�6\_�f<z�t]p����q[2��x!
��#_N��1���*c�_5%�y�`zS��g�#�C�`�l���J��<P_�3�S��O@^IN�M%������5� ����6��u�k�G+���� �+� ���d�{&�F�vt�Y�g��1���@&�X��KXg����DG��Ae��j<dIoZ$Mf������G�53)�;~vi�9�o_�+��/���F�X�"t��(�C3�F(���AY;��Cx�����P�9�^P=-�o�T�$��ZHpe�(l��f��7�d/��F�/'����y�Y3z����H�DA1�z�L�����S,�AoB��>�*�����.��;������Z�����|��`��l���vg*���13��r]�x����3�w������D~g�dx3��'x��u����p��B�M��H�����W�eo���aV��M�����@��O���QE9�[�����5+���q����g�v���`���t���<{/GZX�(��N%�M+�L",cS��\�(�fD7K�N2����p!H������a7���b[�����	��2������5��:����`��A�Q�����8��p���
�")I�^l$���V��F��3���$�l\��1�l���~]Bj����W*�LA��&�6�oN��h� ������b�X\��,@�����x����@<����.�G�9OQ�]?���o)������C�����i��c�MV���������}�e��Rfc��5���
TXC;��D�����%�J���=��w��8���1UC�)�n��
OV�������q�����1�
(l�u�a�x�Ce��Y�j
F�}��������Nggx��;_�=��{�k�}o5��������m�8L*�&�$)I�#������>������K���R�����Ek�=��o����>>Q;nw����U����Zp�&����X4b6�X�����i����LK��:ff��qP�O#�q� ���������j*��).!�L�#�>����>�yB4'�z���F�(�#{���� a���0����'f��kI	�H�����:�:�b��q���?:x�d!�=cmD��#N�t���N��:]+����vx������a#�,`*d���^o�$h��^G�9��2���,Wv��H�1<Y�7e���)��z7�W^��GY��������,����k�ja;����������s�4�������3�x,$f�X�����w�)�`.'�x���S��fr��2�X��[l����IA.�horQ?H{�������	E���]l�@'
5>&���%v�0��j�!��B��(�{��������#�>�n{��&��I�>���h�d�l�G��]Q������#���O� %�?bE�f��M��?��U1
��<����8�Hd�U��3�� 2z�i�]Zg���;8���(�������w��`�V:V��g���=j�����G8Z����Z�����M:�!�vG����W4_p�����f��wX�r��:�{��w���L�<�"Z�p�p��{��3�����_��fax8b���GfY�h��II.�UKu]4K*��� ;����T�+=������,H��Zrr��&����;�`���(�+}H�_U�Ck60���f�}�:��I�` +���,���C�Q7�|g1�=�����E�����6<�56<����8.��������fu�+�W�#��m\N�����#��^�@����e�F]Dv�j��q��x��.�a�������*1$��j;]X�
'���
������r�oF3����	�^-qd�V��]\rfx��JP-u�<�s�^3��"���#b�P���"h�Jz#��xM'M"7s�9�����`<��2�Cet�cx�E�Z��	��XV�q����=�����C�?b��TY�i���ho�^?��D[�zb��N�����(a������OD*yd���-w0�X�w����#c�����s�����_�@�m���bct|�����^/&��`	����$2u��]@�t��f8&|��{����y���������C�����*��'`J��Z�6����U����h��&7T�S9�EOn�Tf�������6Sh��6�jy&)3<!�R��[��c��kmqRK����3U^�s�c��dHc��zt����Q������M�`�3���HI��3��g
�����[���2�^�t��a������k�z�g���k�?����=��\a��������jg��q��_aO�����V�"��W)�6}��R,��p@E*���|�����#
��j\ �:�a���-G�_���F': ��s�S$�k�m����h��_�f�SK�	�hyv����Q��o��F�C(��.��cJ�����n�6�O��*��zy���WW�/6�n\N��$���'��u��uN�������Ej������L#�-�Q'{����2T�>�����������~�	4��Qz�����c��k��c�
xo����4px�W�3n)�M7���])#��34e\lo2.��-\�#~&*d|�Y8���R/�\��oaP)���~���o����
�F�l!GM���
�3Hn�a��K������'��026��D�y_|T*k�+k[�jyGc�}�/��������`��L�>�;?�C���m��0�W�4YA��Jr��������'v�_���>^���M�F���u�/����R����7�h�Ck���7V�"e��@�@?��A����|�dO���00���3P���]���*e��H��N�C�C�4}>�$hj-/Y�f����6k�G+��v����R��B�)����HA�*`���9��U��on�(:C��L�W���������R������A
s.9�V	�
,x�X#T2�D�M�
���X��U-��a�n]���x�]f��C��?�o����)w7��Y��g���:>�w����&e����i�6cz28�GW)gP�\��{aV�_9��O��Z%�![oR��K�9\�!5u9����$��Um������U��]Kz��!_�������_��e�	M��:k�t����;����E�i+!,�'�zO���rP��?_�w�(�i��LB�r�����#9�o�Q�S��a�3�p��?��J��*�:��
J�3�02�GiZ'L���u������|l�[j-�[���o�"M��(l>���K/���Dc�|�������y���yc����!�{��E�T
*]h����Wr�8�Nn�u�9�%��u�������Bj�����g�4'���%�������ljn9oN��t������1&l���!�do.�O�Y��q������"4/�%h���.�/?�]��3e�ci��S+v��������\�i�0�Z���4�x�R��$��7��:�M"����0�Ow
*L9�E��WER�}������1���<#���so��G���e�>>����4���^<��*1����������@��
��
�
�[�������c�r	�J^�#QIA�
=�D�BR�8�gK��=�a�U>��i�����1aRt��k�ku���S���t.Cv���Q_0���I��E����)/��3'�x��?���j.,��F@-��Rgi��A�,@�P�H[�g2�i��3�|�j�����4	(�p��8�6���1V�\���"�1����.m2���(�`�������f�Url<-6��$�pRol����9
��f�s�t2��b��X�K�(�3	�V!S���a� #	>O�O��i��pWj�����i���k��_�~Q���������f����_��Hs�q
���6�
(�*t�i�"��9{T����Y7���M���w.��\d��
��c����'��+�O��7_��t�99���SN����	��FV�;�n��ag��
Y��9Q�Q:��:�2I��$a���F\���������]^GlmW�J�5_�\w4���E�-��A�oqC������x��E� �RuBNx��\
�H�@<�I�I���3z��|n��<��z��Ef;�������"��C�Q�r��33�e���Q,s�����,0�p�B�����C
��9�^ua�ibEzGgI�:=KB	��{�x���\�@��.��}J��z��!���u���\{��v�(�E�$!���V��?kg���'���(� �����;o�����R��1�>��1'��] ����]�W�!b��}��x�%&^w}������`��}��^ F���5��32�F��
���2���g�P����*��R�����:vO=o������m����L����d���kn�eR��i�q*U�7s����b~I���c����,�$��`L�����z/�������[Y]�\���>��e~�!�Y_�2�'�Ma�2M:�J�/��s'M$���%��N��H2nmRb���ji��ab�?�;77�g1s��Y{p	������X�C�.�w��>1H��	��Ox��~����]��~�b{���@����G�F:��I��x����4�u�w��hK�����IY��i�u(�)�%:��z�pu���Bo�T�����������C]�s"K!P�*E�������:9��3^/'^���]����:�Q5RpT1��h8��A�� E�5J�i����h!�<��8g��s� ^(����Br<�Z�	k`Y]l/�X#k���{�w�������7���7gV�V�*W+��@p�Dh���k��-�jG�f��C+J�#���
� �y��d�D(/]1Bz$w�S�T_�
��~m�=���8}�/@aW4�7��7�f����8,�B1����B]��`gI�P����k�h���Q'�	�D2�C3~���J��o geZ����$��h�3� �%!I��Iqxfu�X���;CN0;hXN����P�>�n�;��[����E{��`CH��2$'l����
�U���l�r�i������x�3K�S/f��NA@���
�]y9�-2��=�)oc�-imu�l+M63
�����w�j�]��Hz���Hz����=��y��`Z����%���u����H�B�;���HB ���nz�T�^�;r=Y+���n���0��E#���9��qX���
��3�M�Y����fiq�Z�Meij#bQ]�3U'������ MX_inw���N���j�4"F���o��
�o���w�o[fU��������%��zN�9�VFi�X~���)Cr��3�M����ff���B��g����o�����`y�r���ry�Z������-���jL���
��&?b��q��yQ�>S�&��/�1]�*�0t.��H�v�Ea�u���e�s����b�F��x���R�
�3�o��4GP�����V)���B9�#��
�=���(���?�X�X��E���$�����^~��)9�%�.,lj�����i��W&70�U?��^H{|��R���+��t�0��Gs��C���<�����m���������$�p=�|?VWW�~b�\��M�j�\��Rd���[�q�>������Q�z�Pw�0�cU]($��)��o�1������Wr���^�P������?���'3����
�{D��g ���h��Q����i��,���9Uw�H����m,����2�fW���k���C��V���g,I{�z�����T�������w�/��w �w��p~w��'���=��~����@����y��tg��wOB�V���������������o�m����GGm���Z��s��F��a.>�����&^�*���9�\�II�G���f]�T�Glqqh^O�^x�-8Q8�x��;k�f���������5�������"�h����Do�I�)���*  � ��d��)�� `��e�l\��� ������+��r�E�A�:(u��!L
������FpI��1�R��,
=J�D�|��B	�(KJJG�@X�PR>�BIC�x����<�(e�A�Q~Z
�Hs�	tF?���B�RL�%�
���u��R�)o���2�Oj�a0���������=W��W�R�:���o�+N������M@T�580�{��b��q���O�/�������a^U��'�s�������d���E�q�����	���k���S��.j[�"'~h�qYO3������3,�>|b�(���a��.z�5[m\�:���S����������'��r{��2��BScbO~h���51��ML��������31��/��?=V����\�`����������G�e���
�}�q���&�	$��83$�O��x	���>t���O20������)�I�UI{����,<7��
�Y���oJr�FX�������P�P�P�}��zff������P��d~~�$��me^X�����J���~�������x]n���E;^]];���_���aHs����#I����'����A*���b������16~:;h�[{o�a1�����fJH.P?~w���(aC
#TN��"��61�hfx.�����
)�76?[?V@�0��X.�,TX�0������@��K#��b6Z��0�@�d�)�����a������`?����HN�
w�@��b6bA/�cfs[NC;5^��0���.������Y�o�{��j\])�d������4��P���n5����������(g"����Cr
��q���nD�UP-J�M����v�?�
c:z�$3���<9;9m6\�X#
^�����+�y��}��_j���\��������r�$�%cj���"�G�I��P<�C��Q�58�%��#Z"	!X�?i�${����N�H-c�L��]6�9�&J�EGo���O0�'�i �"Q�
C��F87���"�
�X�6�,���lg�ts�8�������y7<kH���m�'2��7}��}���G�3F
�����C��$o�h�Z&�D��I"���"2E"�F�?������;�#2���j�1K� �����)o�(O�e���Z|�����c\�p8�U��U������������a�q4�����������x[ ���)���u����-8��p��	�4�`h��4��30�y���{,$�r�q%=&�L/G�06�Y�L��e��������fe3^]�n�mm�[��36�4��]��&GM��%���g��������4���0������@�+����P����Td����onT	
,+������^�XX����y�}�y��r���0�l[#��g��v��oFIL����c�2��@6���\]�����R���Q�Th�T.,�0�Y�|,������`8Z.L`q�z�R>C�	!6)����L
>g.W�x��������f��E�Z��hBJ������2�����s�X��T=��}Z������F� iI��E�cVN���I$�6aI+b"����������������/��A2C����d������K����n����/�$* �����9>w��`�,<������V��e$I�16��m"��u��$�b��2����)����y��.��R*�f,���_������n�6a����,I��+�k�Y��.�SY4��D����R!����jx3�6`�*����{o������������~���h��w��![VB��=,�U;V���S���5�V�����T`b8Pk��d�Q��
n���9��N�c��[3F�0=M0����� s���o#-����������V+�.���B�����U�����u��x���g��d:��	3Lj91�T�;������5��/.*���tHI�LzY2U�U*��h�>�9����v��7�����~��C�Lj.���!���`���_~����$�^�����������+n�ch�h��>���{��PT��l)jb�����G��x�w�#���>p�QY�,��W^N��v���f����Qgt���_��Z���>���7�8i�K+&$t�om�\����u;��8	y��(�+����v"6.0�6��g�K���h����shy��������X��<�k�z�������^������fm���;��&�������"���������	/��|�J�Z�c�E@�@�Z�M"o�f0i_����O�m��8�:m���tW���f�Ar_f7L��?����&��#�?q@��8�N7�M��s+�����G�N3�h�6��Y���~�zw�����
�s}��D�L:��sw>bdr*��r����1�AM��Yb�^g�me}S����M��]�I�]�A��o��!W������Bh��K��@����]
~���]H�����EK'�GR�/�E�;J��
Y!�Ro�cI	M��#a3��{"���u_�#���Y������������eVv��g�����=�Ex&�9�A�D2�����}�z�m�;�m:;[��������f��]N�m���-�}OTQ����A6sQ�xH����>�?�������������A���{��kO�<��K�R�I�* ��������2�,,tM8�h��.��5�q�A�~�����e-`pJ���`'��
9A�	=!�V�	�zU"�~��kU�+h�`�A��V���9�T��@���Kc������	����

�2�Mg�m�*��U�)��PF�spxd�
'�M�X���4��.>����p=�&��\�[���p������7B�tI����U{r��H�oA�����-h��g$0��hB�*���Sd"��\4����x��NZ#��������/Z������~)~�Z�SI'�6���E�%K���.�v��3t�7$���-6?�[�b�*T{F5B�_���������j�����jx0~	h&��>�)��������w����;�@��������2a��Z-9�Hg�W~��Bb���iHw�BS���H.Hx����tF�����<�A�U��NA`-y��1��x�������A8����p�r%�K����7�U��A?R�6�QR���0x�~2��a�7hS�@�?���m�t�o$�a�m(LW�yq��I��CS�,4�F�(!dv� �Y�zY�{�9�VZ9ke�|�������� 1��5�1�m�}y�|�3�5RI��6YX��:V�����5�n�MV�����q�>�]���u���h��/������c�oc���n�����_���{�U@��z�q$�%���C
���G �F�v�1�o���J�e{<�A����8���a�����U�<�V���X-�X��Q�W���������:������f����
���N��}|�t�_7�gH�@���y`E�7o��oj�zT;<��'�^���j���q��}������}��}T;;��_(��C0�F��i4�QG��������������[�8;x�|�|{rv�:����M2�.o����@6��^��=.����Gc��_W���~5�O�vx�����h#O�S�_��(����<�k����������w8��'�:V<|��j'��zc�99<D��'���;RP����)�����he��4��'�{������{������3������?>���g�������	@p�����]���X?k�13�8�7gu�����n��	R�pv���Gt�.��N����w���)�9�.S����$����C���yT��6��[��h��N��w
��wg��x�wXg������������:-��Bj��=|m�^"���^�l?�����o��cw��N(�?y'U�N�7�H��aY��\�x�d���
~9{��_?�����Z;��?"�����"����w�����������������3�����#������{j#o/�PJ�aY�����������3$o��<�lr���b�^��`��7������>8k �_������O����3�����C��'���g�:���g'G��w��^�;�u��4``��G�t���S?��",�9<y#{sVt�_|H���N�����O_�����v�����������=8>y���������s��	��g�
�mm?:8�������Y�=;�_N���'?�\4�?��������V�vB4�����=�~h������|�����a{�w(���������Sc?���{���
�S?�y:���F���7�jo����
��4M���i-��q����������
f������`~���/ �8����1��s����Vu���O����
���������t
������5��/
zp{����
a�'���F���7����f����)R9���SZ�e@��
�R�pr���I4�t�-�\tB�
�,L������a��!_����M��O������Zb[�R�d}?����AxtzV��SO��AC����u_0u����/G�� ��@
�����]����k�|���k��S��������5�3�����;%B��s�H�/,��'��������:�� ��0*r.�xO���?Kn�qQ��:
�P�v���q�����=���$�3������z���1���a��e���7o�5J���U
{_�!YK����'T:�	��/��?4j?�Y�d!E>��`�F�v�����
��
:���t�/

�	��4F��3�h���'�88V���`�4�"4����@��[�����p���M�=BK�qm�v�q
�� ��!���!I�o"h7�@��7��A���	$�x'�g�Q����Q���1��YtG�!0���A0�� BU���^n���)����[�J^�}�`�B�-������!5?���O��A�:[a�*���cfy�;�R*�o���(�D0�7 #���A�����D=<C
n?����?�h�XL~w����1��PVkE���p����t������������'P�����)�%D; �������o�j��x�FiM�D�X�{��(�|�����$�6��g����{��=sZX�@�����A�'��H��i��^*�a�����r��D�R��F��
�?��W��j�"�W����f�
s�Ln���9�X9�Qn���o��8�q���4F�@���'�������Y�\�N�
-�$��5D��hEY~R�����5�DQ*���tw�;�N�<�?��U��
��I���p��L��rM4B�IG*�5�-G�!��`�����1���d'��z��n�%��
���]-��
�t���C�����$���������	x,�b�m��%x2�����M��������m4���.:����i�#��#c&�i@ZQ
W����+Qfa4b?#����I)��,��z�2�l�e�X���O�m������z�Lh�X2�(�EM�H���������S��Lc��hB��f�W��Eo�E�����@z��4z����e�L�d��m����o.�!���}���>_��������ykw�7xh����>������A�1�*�b��`���3���a^��e1{k-��}'�����N�Z��S��=�����}���F�������+B���,A�D�&-Gg��+9��K����t������I�~���?[���la!���pZ�*��.W�+��:1�6���|
����KY����aCi�\�K�X���R�\���x��A����V��8"43p�C�4��R�8�D���'�XE�,y)�K����8L-2Bi��R.��Y��7��y<��X���g�o7t�s~k1���i��=��Z��Zg
F�����0���p�.�����V���O�	�����Ku����J.��
�o��[.r%
H���:��2��&�L��@��,��Du�~z�Dy��NT��o0.���f�_T�Mu�����s��s�+�)�{y6v8��h>z#��v��l2drM-�/MYe�K)��Mq6����0��}Ez�J�5�|�&��'����x�l!�O;[o�x�^mu?b�K�#��4�;��jk>���A(�����'v��s����)�(�P��H4������,W�(�[�s������El�7h]��7#�r�8��������,���K|������g�'3��2ZI0���%A�����"J5R�e��c�*�����*t�5%�i�iWD�|�x�
����#���d��o���"��a���Cv����G�(�:oA���^��r����-	����sCQ6;/�*HT��if��7+3e}kD�����On������yn9n�R�����AA~F:��f4�����v��A�w�������A����Y��%�!�������EOOYY������2����$+�X������^����7Zf�K�x2`�Y�x��/�*����`�*]���������z&i���d��pH��jpX�������e���j�O+M��4��3!~�8��U���@�)�\��k<��� f���Z�������F�������qU�4Gd���%��_�4l_}s�I9{�J	��R�|��@�� l?�mD&��eP�7
!�t����G�����.w!GkdEm^Q�DJ��7��&�������+������pV������R���������EG�r��]����]	�N����>��3[�Iq:uKb�Wj
(�K�"�2j����{����6�F����+M�Dl(��*�`����4o���t������P�f�^Ef�(n�+�0�q�c��(��CV_�z���p�l	�����k�����Y�p����W���~<;��i�(x5C
���}��bsso�����33E�*��abv�W���z��&��+�K�U�L/Y�t�V+Qj����GgH ��/�ziF:�
m���<>�J Q],,�i�$8�ZO���<@����gG��s�����L�d���oy�S����"� xy[��3��.���Y$��rN4��9��)n��H7O�\if�:�/6��YE:���6v��f��l��=K"H^�	$p��c]��������D�q1�3���#�_+4"���g,��������k��.�3[�	�;���<I� 7� �46
���.��m)ww������;d���k��bA���b�a�p�?A������z����Z�'�uLJ��M~�bR��rZ�S���d��x*��!`������8v������������q=�,,j�7d�5&W�/������q7�|�b�tV;=��aX4y/:�9�����0��Y,:�7�"1���P
BR[�[k�H�������
-I4K�YK�L�9a����H'oEA��J�,�w�
����S�5w�?��ut���'���&�������T����:��\{���==�e�wuV�/f��D;�~{��xs������z�zZ-$�� �[���_zYZ�~��Qq���+����{�q�U���t�$]���������~wfJ4n�P�I���!$����%E��8��vf���Bm�	��;s�G
���o��8�t��������)K��K^�%���3���L�k��_�;��ll�n������(����Z��P�r�����F��������0�4�7V 
_}��1�n�D��&�@k�HT��Un!�Fva
���=�v5<�V�@��}������I��o��i��Q=d/^r�p���W"/Z�����]�R���2���f��E%ql3s�t�(K�s�#���>����Y��d3����C���(
D(	���$Y�~�_�g��&���i��n�Cw�d����t�������"��f4u�e�9N�P��[�'qn�����<�?I�}�.!���V��o�'�����ON���]������
������e���FfuF��1��D����������h�qV&y���>(WU�E]������U���������W0
ZR8R
g5����� ��f2��<��>~0!,N��Lk0����M����\�Y�*1����0�w������8'��9t���2�*��iI�/Pn^S�M��F��o1yPP�
B�	���p����x���c�K�nf��9��<l4'
���8�&e�������Z,��J&4���wh��G|�-?���X$�]^��k5I
����R-
�#'�E6�7���q����n�/�.��.!8��{8%����K'���a���J���fG��z�2��[V5k&�yNR�=����3�}1=Sl�W���p<��}���-4�9���o�O���7��|%acsc[��ew��|�Ym��<�������S�mI�Ev��T�E�o���	��P(F��"�H�66�s;�2����������Y���X,����z����O�Oz���A��{[���K����~R�8��1��c�T//$����Na�'����1��$Fry�!����f.$���\����[�*<Y�x$x��E���/��k���t�����{5o�K� ^�'��R���b���Tg���������j��P����u_���AXI���Micf��I��#8��IW}������
���R]��lWfu���*���@�	>:S/U�G���aH��m��Nu&Fth�>E�P���b�CQ]�_:|���0.���zY��S��o�a�%�m7u�LX<��%����_���I���E���"���$/	X'��kv�1���%v(o�������R2��o+U�0l���F����'���*� V)�a@=�����tjs#O�T8E�L�!��R�K���Ld%y"Qv�����$���$���j�B*�Z��q������l��oe$VK����/��	�����\Z:��$�0*Y(#]��{"�z�n�-������Q�U��$��-�����k��{�]�����2��r�A��}������
����#:�v�o���h���U�hW���.�������T�����K��om^T����������z��3&_J�Jb�Fw)qX&��h8���J��";���&M�^�3��h<�x������)*���Y�\}�J����-������:���p�g�7���7�[����������x�K��_�'�����?6~����~���dn��
BJy#���������a?>~>�/
�8��#,��6����t|-����*�`���cN�UkY%�% V\�aX�����L���K(�I��lj��� �0T����� 0���#F�t����
������!��/C�ng7�-*3p@zz�5�]�ft����Hi��2�"�r�Hf�dC27��@Y���I���5~F�`G=2������}8�hZ����x6�
��Go0���)-w�
��i�v��r.���Z�J��5Np���0�����<k�L���n������6K����U�N�c����	�5�"�3�i�Z�����sf{f�'��x�����Q\�����=�-i.�X�v������D�����A��Z�,�i���<�h�����@NK�]4�Td��,>KE���R���*iY"99�Q�/��U�i��G�u�}`;�g����4��D|��R%2�,A�!���������<���d�HJH�&�T��.R�<�����JNl
����`��Q��D&��u�^6���)]�J<���*����)F�y���s�O?�����m��q���q�Dx����z!�����v8{�_/
�v�gr���x)����r�h��~�rC��s��3�Y��ty#y-��e>Z���>L���-���z�S��
��p2���q�HO]bN��V�:���:�T���f�o�����z+�Ugt[��)�D�,��F����O�1j[):|j�{��^�Ex��	R��J��pN��S���k�X��K��vd~~;�������@J��1-��������6o����=��6��\0��HO�{b�>�c!����W������P�B\(7B���[�oZ������%�j�(��csV])p�5	:��	���E�N�g{���k�-Lb$��HpkR�Z���.8�-�g���M 6�-F1>�� m����?>���iv!��U�y��� ��XAo�rGC�����RTS������PaA���v>&^:��y�O���!t<:@����S��>�&q
��w���������vY����RK3�����U�{�4�?[SN�wi�J��Z&P����	M�!�weS�:h�l�#K�b�av
�a��nY������n����aou�A�2��Kk����V-o5<��0w��t�����H��W�Z���1k��?��-
������F}(?mZ%1e�-=���]��X(�_���3��-�k�y?��@�
�o���}��-���)J,���k�^���<���C[Ga�����a�y������K\X����M���+������=-���2]��F���q@^���*����/��}T=�����f���,|5q7i�,yt������[���J�F����z0#�A�6B����o����O��i���B�5T��*�O/(#���:�����Wj��������XP5���R
]~9��sO*��B�O5��d���"�e=Wm��a_\`�D�$�=~9g����-�,��a���
QA\���2Uc21q�h���t	��'�Gl��x��_K��R���1zn�H�$�����C�	�������m�	e7[<��a
	�	FO>i�#��2��<�����p4O�&
��#R#�'L�����}�����p�6��-��{��>���Vx������r�}�ct�U��}<A������F�V��'�V
d2X�����x*[����Cz}�=WC%�iYc8�]��~�����	Q�bp�i]�qs|n��t{(��oWA��{M��������p�"v	�>:���P�l�6���d1z> @P*���6����5�*�<JnO|DKk��i���(C����4Ai����6s�������2�xbFP�-�
������m�2�L���&��Bs��#����\,���0i#�,B�!��H= ���v�L��U��=h�{�p���,+Z���'�#K�����tp�%)�G���A�F�$ +����B������������c�>z�j�0�<7�_�q=lDZ��$���f�RM��&���@����p>�e�{�N��y�����W�p?9��U�L���mC�\z��d�o��3�J���U`�p�v� @���@�%��W�e�7ci>u�a�s�?g�:�V������eIg�����I$���{���6��\$|����;��T��!8t��L�j��`1:k��'�d�{S���1hs��H��*����l������\a��g��bT�/I4���Q%���i�����J���-O�������-��&I
����5z�J���@d�H�$$!fG�����������?�	tlZn�6Q��w����E\�#�D��a�3������6��G7���3���&�u���S��E��Uo0-,�Y��	�!�&���O�N�Of��$�b��\��*7�yq��,,��A���U��oG���	\�
��5��`���
�V!3��y�<S!j0��:k�l�.��L���X���
R�7Ci�`�
@�����.���.��mLo�W�&adR��5��Py1\��a���T�
5�8�6�
��H�T�o�Y?��Y�_k�%�����Kw�����dHfMXM�^���1jM�0�prVS,$HXl��[o9_�����*�0J;���l�h�����_��S+�?,u�i}b5]����WBJd�WP+�R����,����S�c�&g:��G������:"�
��8����h��^�C#��P9������������b1L�x�a�������z02E4��*[t�
��`[���� ������$�>���C�����^����]�;�r��?	=,�����m
R��8q[|v6���~�>7�l�)�5TduM$�;�D�F������������o�4G�'	����L���IIc�u��"��-������e�iI���m&q���2O���������V�[z��Y��{?��3tc<�L:r�	���L��\���a��w3Lw���������j�j���r��-VDxc�;bi�Mu�D�&
�<6�di<N7*����f5~9jV���3v������0S�qmR�
F�n*��p��OD�����im���=�V��E,�,��K�|&t��b^$����`�L��\Vh��7J�[�<-���eN�Zx��+�$~i��a�1�)9�`�R��*�D�����	�1����u�kxA0B-aC�]�r��j	D^�
3�&�Z�QcW#���q*��L�W��w��&��Q:d:0����P�Ad���
�������*r<�|�f��fv��6vS���]���u��~�q��7	L)sF��
�7p�����["����r��-'7Y�Ve��A���`��5�D��B����9q��|���pS��;`m��b(jQ��������K(����F��hA�p^�x5�_���;z�����h�a���yWW��K�Mk�d�G�����"z�z���p_��M:=
�:>���������j��d4���M�-����Rd�-QG��a�h��9%��x��i�g�V��6�sS�b(��>�IQ�Cee�Ld��;�_�3Bh����������=4��.����L���"�������k����������H�(��
��!��u���L�q{���Bf�Q�/�_2���qs~�|$^3�9��w[���DI
���^O�(}wJ��T�.�Bm)�4��vy����{�	o���.M�p<i�F�����T6q13j���s
�9�������Vo�,!��J3��l�������-&(�F����X���P�5��q/V��K��"a�����P��4}�T~s�4�����<��}�|lMI����A�����PD�~9��J��5����d�l+���]�����R,\n���q���7Y<���zq�;���U��Pg��[,�*v�H[�P)�Y�5�Y���eO���(f,9��:8��M�"	-$�p]�3F����-��j�q��}�{�^JG���M��,t"������{e���)(��@QZ\����v��
���@��F��{�YK�O���^bn�������}%�������U�8�	�w�E��l50�����bt�d�y3��#r��I�n8���y@����=���)7cJ}��L�Y�&M���L�b��,�������QG����p>}�U	�q��8�!c����r�<n�2]�*�	��(���'���X5��&[?��r���:��%>@����(�<R��h���������m[��PH	�7������������f�����"H�B������#�|�&���Ja�X�k1
`�zX�%F2�
<!3��E�o�T���tw�)��{D���
?���?�Sl>Z�,��a^*����Xj4��X�E��	�5}��rfL�����tL������;+�E�0J@3�z �`T���\�z�b����z��jj7i���x�k#��]��<fz=+���C�kLK�������@H`��S.�=b]*�
�1��o�
��D:��m���r����I>��$�oa��u�����*��4�BxW1���s�3�R�Jw�3�������.�[sN�C�}
�t��'��K��3]����>�0�����>K�n�#�X��N]X��`��0�����yx1��Xk����F���j�e~(L�Ar�����fV����}j�{�n�����;h:F��p��������Q�7�����0>�������m��3O�z��0�z3T��p���lAz
�,�g]�-Y�o�c��;�n>���
�"�L��'&\8ph�g�A�,|�oK��T�|�7e����U�3��:W��2��:�``lT���q�S3O=l����8a��yQc3g ��2N��p��zK�����~#��m���%^it�DHjgF�2?�s��"��Zf��I����z�`�����W���,��]�x�,�F��-�u>��pK���`K�Q>����;���i�5)k������%-��/����t�sz����s�E�l�Y2�����;��p;��z����3�Y�����������Ao�-���������!C#{�'yJL2����/���[����^�u���e��ip�0�(�S���K�{Fwe��'��l�J�po�}G<�w����z���?��d����v�����7�C����?j���Q�����<E��o�>�]d1�Z�������XC����<�G���
����A���������9kS�E�G�z��Q�'����2��C����������WN#����Zm�p���,6aF�G�x���(PP���
����6�x�":����q�r�0��~�jN�3�m���;�N���q�&-�x������_JA/�_y����9zL�x4g�5�gEV�}o$��z�1n�z���0K����;�V���I\��'$���p-K2y����J���Y���g�^��o3�2���bM��D�9'.��nh���#���B�
@Kn"���hq��z��@r�-�Hsf�3���9�������-7��xk��bc�������p���{in��Q�������\�2�P�bM��C;�AZ!�H1��[�yU^�6���8<�O�5
U���\�1���������A�P1�������Z���^|��T�I��?�2�c��.���J�-��2��E��S���BD����l�rO�(�a�0~z[?�VWW�R�����*��W�4��,�)��_j�[P��z���a.)Ei��T�A���{�W};�w���k�m_����qa=3-�G��d��L��A���)|9"3�pB�k3U2%+�@��~��+�Jz���i�qQ��e����E���@Jb-��~���9"����m'�GM���h��eRO S#������������C��|�W�h-J����a[(K��l1GG�+��`!���������Y��HP����z����z�J^�@�t.������P�HTE-���s��<_=���
G���+/����]���
U(X����aB��|s��L�t�n�U��ws�1R����*�d��\����m�)	Lx��G��Y�����x����D��0��L�4�_�@����
������?��]���K�H�{���R'tR�!S�	�Y���P(������i*����%w�B��~=�/-��������EeB4�B^x���y(z��:n�)~g��rdH�?����7�99�uCo����oFk�)
�1<h���Ch2mR^D	 ��94���i/������)��7m�v3��.�|������n�Rm��g�T�+ky���[������Q2���Z�/��i��6��GQ��~X��8��1&���J~&3[2f���`�ZJwc���\"�#?�����V],��e}�[�!N����Yu������������
�np�$MQIk����`)���Q�N-b����b�8�����*�����*�����%���P���`q������������!�����X}����I �LG�"z5��()40���Xd0||�=��9���� '_��'�4kE�����6��o����cl��M8�����5=���X�XT
����p��]����[��V�U2
 -�w 2�����")\P�'���pt�����r�����Th�An�^�{�
fA����^;:xv\�T'Df��JC[����9kCv���s}�����Gb�-�����ism��0���8�#e8u��hY
<��G-��	8$��=���N����JZ�J6|��N�NO�zz�������y��QO D��5h�@8��;(:��S�74E-P��,�!�y4���E$���z��|F�c�r��"���J��x��og;���&nrZit������HY�fb:s~h���O�Dv�D{��������wj,e�R+|�<�'�~�c��!����<�xVI/
����g���B��p�[+M�Z��E�k�-���������m�����E�J�E7�L~����9���E�I+��;���I"�\0�U�.��PpS�9���&�	�������i&�hx���
���!�<��f���^�a��a7���v2�q@�HY��r^fF�5�T�������f�4[�cS�?�y���* ����V�G��^�F4�%0f��[�(5�Gj����;���0;��\ ����L<pAE����0�S�����5U�O�-����-���K/fR�(����3��z$h&��bha��H��HhP=�OJ��q,g(%��f�@�n�F���q�8����������"�T���LS��R�w���,*=u�f;4Z7ei�]�,5�wDd!=4����N)�;����}B)�Hb+@0M������B���%[�S����.�� PE��^)����?�'��+/������Z
�cFq7����:�:%+_ZQ4����v�H+�%�K^��B����T{Y����L����0������ofq�d�K�b�N�`����^��W~�U�G���!���F#lBH&-/���d=EsR��i-�w�5���:fA�c���if���0��Fm��=��f����F_��W�V�.�6�fiw�B6g��1�������U!�ZV�����{�B�a��=Dt�2�L���*��7i>8��^�	�&{3�,��'�f�	�.Vg���Z���T�Sn&H������1�������v	�;���`���03��:�g�Kf��G�f�Q�K;b��:������n��"ZY��M������������XD�Q�V;���2�z�n�%�����*����Nu�b+*��m��?ZYY�������\�����w����h�>��<{����{��a�}A���&K�[�������
WH�x������/� )���]z'���j�k�L<�l�t�aX��m+U��.�<�B�����0��u����{��}L�A��
B����I>��41Q���4?R"���������{f��n�E�'�j�ro_��B��d�H��cy��b3,J��7�NR�|�de����9�8s���B_��u*���������z��>������+���h�n��~�Wo����2^���c������b����w�VE �����79��.,��}�@Y��7�$a���}��;m`�-��n�o'��*3�����fi��9Lk��*��o�aW��B%���C�
{�E�1�t���4�/�N�X�O��<���qk:�����rz���k���U��]Sr�'km�f���U=���vi��Z�Ry�qJ�O���k�������iT���+����������5���j	����l$���,&��z��T���-����Dn@��*�>��su-���|�������L����4�.��i�?y��N�u9n�y�k������20�����rHHr�D���r�\���Cx���=Z�����
����`V��u�4�|1�;@m��8���7)�;� ��g��a���\��0@�%E�������&�g�
�l��a��H��0��:��0u�
�BN�=����"3�j�^��2-U�@S`����M�K�v����Q*W�����RyW6�B���+�����Zx�,<����W��4"$�e��+d�e	,a����3��ts�!��2����/L$J��Q��p���N	@��nB>\DO���bV���[)P�BR��NJ��l����%��DL������PL qw7�g8e�������VE���?q����m�Tc�.�e[����kI�0�dhX<	0<�[[�-ol���;jJ�z�u��������p#�������X���V��3�@;���L�m��h���w���h%:=i4���AY:=�{��RN��he!q��B.�yYG�,k����n�����qW��D@r�����:���K��|q6^-�l��9c���F�C.+~��&��u�yG)��&������:Z�o��At�����Z�Zy������
]Uj2)^����*/
��k��������."K
;�J5!�dRL��T������WtL�E�(H]KE�)F�Zm���V���u����:�J��^������s)k��g286���Z�qu~���L����N�%����mda��� M��1�{1���������gm989%�����0�^y9�n���q�d~_��w�'�Dl�����������X����C�X	�ACR7������/0.�ZF��}�|�� �4]*�����O'>W�r��h�=���E��+����	9��nCh�6�����%��"M�b�a����)�S��
$��
yDu�7�}��{z���(���
	��*Zw��
���#�V@O	�xIE4�"��C���#�8n��k�y��(����B�Q����(����;���{
�O���f};:8f���3`J���E�%A�w�u���D��n�j�a�3���q;��<$7�����2�|��9��M_��T�0�U����������)������=q����wn����D|������m��Q�gbo�����A��)�
X�C��\�� fT�M5�V�n�c%`\��xpB�����#�x��n������Z.o����k�;���y��&����i���������W�z>�t��C����`�_�d|}�/>#G��p�0�$ti|I�*x���������������B+x������Y
4:����n��E�o�W ��U�]�"{a|�J�1���*�����b������9)E��zP0����������Q����P�jo�K��{�4�2�;��+��0��:��X���yF��K���p2�������]M`=���m���� �*/���5.��K�-���$�B������w0<�V�p�5`�`���q@�WOF;�}����X+\~_��a�}�7
�m�G���6��9��7h="�L�ct���1�SU��
��
����m}���<���3��2������2�������?H������C�+��55Z����^J�1�lb��!�cA�v�E�"R������Ed��	2�0�?}q�����8�/.���������n���U�+.DX���6���&��x	f��p�G^#.��-�L�i�K���3��W�ln}�R���
CeO�`tK|pR�����zD{��^�@����/%��������@wG��"L
d�Zu�Dq��~-j|!��bw��^���b���S����Q��5fb��K��������/:����.�k�m�Z��J���{<�(��E����a��f�Z*Wl�� �B��A+�o���W�
;�_^�.����j�����������70������������q�E�������rEl-�U���vz��]U����U���(����j�������������t��Juqk���-@s���@�C|��p�������3|'�W��X���Q��YP7�0]kk�m�������q�k��`����U����
��~s��
j�_�p�X|��i�.�
�����P�u���f���je���J��R�Ue�������]e#W�M��f�*s���TY�*�|��kp����-W��@�Yu��������i]�Tp]l���a]t����Z�d��n����e\|�oe\(�F4������2����2���2�a��2����2�A9M+��9W��Z���]WW��PPK�5��66��_��#(�k���:8����j���V�J�/�����%�/5\ ��Uk�����~�=W^Q;�����o��R�o.������-p�
o���#~�w�8��
�����x�_�5��~2�����?�X�
}9ou�K��P��m]iB'y������\��=��Eyn0f�d���/���X~N�C;~�LL����u������!��;�k�{�V�
���8^�9;�$d������A��5��>��x�J��Ik�w�H�c!��ZI@K��*��f}a��Z�}�&=z^q��V)=_OBP�PY_'<��
2�����a;��g0[�
3�q��"�JJ����Q���H�2��&�/M���S�HvI[h^7�{�No�����za�H�I�Ek���Q7(Z��9��q����-�G�$����woZ�����.�7�#f��%��.Q9n��&�����^����G@W~�
�T1����]�=�-(�Kw��T!"�&�����M��^�O'�H
���F�����MMF�N�>���?�z~Z�M������T7v�S<�9�i������=5N�eIb(�=����H^U���df���c7�Jw�8i�!Q��
�zFcw���`F{�����B
������c�b�R�4����)������$0���]����%m*}Y�db-g{t��nH	����Y"���"L�/����}a!��h	?S'f���<�5D��\d3���-F��������:����V���~3���@;V{� �:��U\�<�����-�����EP�+|h�z'7%\��,��6�h���)6]z(o����\���&���`po���7)F?�����[t�����������x���{�b��v�����)^���x.A��S>����4���������gr�j��V��K>Z�������fwB��!���P^;���K*�"����]��;	:�����_~���c��.1|�1����k��z~��E�VAD}�:���y�������{_�7c���k���A�$����f}��O#��9���")}���qm�N@u���7b�G�[{N$87��#���p�-������r>b�S.����l�Kr����
r��3�P����w�S�
o&}�z���i$��$$F�$7�����f���K&���D\�kt��~q�i\R!F0/0q�,�/IP����w�.F���%�C�|anQ68.��-		����������������aJ5���M��� �/RLZ��]!_�'����p�h^���<Z!�z�D����Hsx�"93�`��
��P�n>�	:fW���9<��B�p�n��5PG��j��pa����b�=<Va>c$�#�k��IPJ�41HiOB�8J��D��cw��}��G�o���R�'�}#K��Y��(�6S{���S�[8�\0��$2og8���l���[�����PD���NiE���Zis����AD$I�(�M{Bw�D�#7��b�o"��/���<�j<u���'D����1_����0���������vg�Q�BG�l�����"�����W���)�Q�aI����;$q���}��+�{����:��
E��e����G0d��c��2a��p�������y������isa��23Iv{�B�k����W����*�����um��9mM��.�R��Z)*����@K
��b]����_�T����R
x�5�P�Z+���-Wa
�NG��3�?|
�F�M�i���,9�q�
w�h�ucW_Z!�����o�A�^,�k��%Jy�3�����g
��P�L"�r�N&�p2�|��"�2&�������g/�Y�����v�F���1r�O������C%�@h��f}G���u-1�����}/��u}���� c~�/'R,v��EO��@���I
�gNF�t�TM��+y���"��`a��lV���:bQ+��R4R
z�*�U���\YWQx\+ o{�,�J]�����No������>�jc����&���4�0di�%�C���@x����v���Ok����_�#�AOi6GC��|C�/JL�OKQ�����o�� ��p����l����
g�]��i�\�]>jTaA>��jF����\�r�Sl�QwOO�����#8��2<���f�����a�soB7T<��5��r6�?���hg`�I���g��gB_�e	�����xe����x�>���t��l���o1a
�����~����rT���?_�kq_R�6���t���q��JTw�{�e��[k����s!���hJ��5EZ�`�V|�~���}����R���R���nv�,�:��3~_����V�m��+/�6��q���5Q%���e���x�a*{�~����a2�;����[���;K@�w�%�0D�P
�\�;9n4���5�3�Fi����'T�s,�k����
��S�\/��Qn�9�6����pqW�S���S(����������.�����v�����kk��g�P�:x����J������')��d5��G�^������'�ew#�FX6�M	`�������R��YL���\7+i���=l*��f@��^=w��/�-�q"`�����������	�����V1@F���1������I�mt�[�m%���v0lI����l:0Y��"������\��'�U���Jd,T�I���@��������>���}ys�n
��@�t����+��T�C#&iR���,�G5��������,���nv�eq�92�Smj�b�L�m�$�B+��!����J���O(4�f�;����]�-��K=�9��6����x�7���C�D���ZI��;����v��
�n}e�:�rC��l�6�R���K
u�Y���R?9�J���������1r��+��n]{�~���}X��C������uKY����
Lv�������A	�O���@W^��K"!�W�T��Y`�hN���ht&4BU�����h��^�+��{�����s�VP6�k8��������kbZ�4��7�y&������r���������b��X�_����������	M�[������o���w^�q��nd��/�������������E�v3��>G���k�`����f����A��	-E�
���V�����5�{:�Fk����@�
�^�Q�-z[Eo�+��	=<�7��s��T&]�pY����#�D+�y4T
���>FB���J����S������9	E�9�=�/����f��+(������h�,s������	����DJH��o(���e������r1����7gD���m�����kT��(iT]�5���]�f�2��Y��_4����;��s�	;�P��1j�x,�Z����0����w'��N����k��}{�����S���?P����,mW���+��T��e5r+`�e��(���`5�H�T�G�a�=W�V�	�#N��)6q��q�"<F����4�+��:_�@\��B�BO;��r=?R�)�����_���'�V�{r��������o���w�
*���=���z�	��	���m��O����y4L��g���l,S�I��R��6��t��n��s��Z���;�C��~����v��Mbv>��@�C"�?
�G��������7�k����o�zO�������,Ys����nI��
L�s�i�����]^��h�	|>:���������(�U��d�~�u��eK�]�f�<��7�y0>��5����������2���ta*��:hP�����������D�[�Q�4�Fh�����en:zm9���*��e�SCT��7��2���~����O3i����D��~+���X�*&����T�����h)�	]m1�:��]o_J��oq�U��T���{�d:S��[&����VU�g�g�������z�������LB�tr�.���K!'�X��5!Xb�{��d+'����*_��v}7X����F<������s��R��x3��QEy7�X�p�q!����/=�s�}	p��Es�o!���BN���H#D�OWA�V�������.�Z�d&�l��x�P��|��v��I�,Nh0��w*=3�V*�u�
v*��1e��w7�G3�9�%�B�
�!�z����
��q-�7:X����Ew�v�E���M:Z�
S��8��g	����X�����_�;���(�2?�n�������vQ#?;��BFFEv�}_��E+)�~Z����������6���eP�wF�(><����8��<�shL��o,�mf_?����o���"�lQv���fU"c�S����%�1C�/FvK���t���]i^�ff�������^�\��A�`�"���"	��$���;���kO1XJoB�D������-M�<�	����M�?o�!�|�lc|�^��������UN�W�\��R��(
���i�3�AW~���n�E"#'Q��/�M>�0���K��X�3���`J�)����G����s��^/�.����R#�]q���quxn��r�SP�$"$��-k7J[M�fyy���Q�O�D�tO��y_V���������w���<?���rqw��Oj	0	(	 ����}�;v�u�3��=�����f��������o>D^�za�Kd�<C�-��l9�g��;������������;��8O�_�[0]�	���p`P@|���>c��u���5���2����_�	��:O��'��J�:�*�>����u�h�w�����O��P�g�G�R�B�2�"~	���������g�!�-�(�Mb|M)8q�.'W�����w0�4������������>�d���"�z����}��\zD=�����x:�?�L7������I��;;;���H�-��w������k|�������1>?�����Lt��	F����*-I�L%��\"I{4����S�Q���h]N��bW	=���U>y�������dm�m����V�Q��faka�`Z|���]�
%�����
e4u���!�� ����2y���0M\v��0�8eC�Q4������/i��U����k�*W���� �fR��A:�d|�9e�>Rb=�������<�����v4Z������A�X���p��'E���"��uJK���Y)��7f`N)'�
�?�F�!5����S�C��+�s��IU�0��oJ����`�{TP���<��OK���i��=��sM	��o	�/�8[��xe�Mj��pVq�s���moV�0(����.�����(E�� }�4���7
�lB��a�Y��oOo�-�AD�O�D(t�~���6�vV��C@����Dq)�Xbq-g�iQ�l����J�7���H2�������	
������9����5c�-'c�2���������h�%�R��$��F�4�l����������3��Tlva���|?��)T]��������e�1 ��{Q���NQ	���a�"���\�i�b;���S0��2�}Qi
_�	��>r�1����3�5h�(�)vn�+�*c����drs���\�*FP��m;��J���SH"��CaV��I�����a�&�%�U]S����X���gP�������F���M8N+xEr�'���:�dT��.�U���IH6��dg�,���3_�Kg��2�A�l	DX���<��B��89P�����r}O�YeYS�&x�/�x��E���o��tdg���(t�e�w���Y�q�e�����d��k��0� 7��7|��O���v'I���:�`d��`n���'9���������V����F��Y����������g�OQr���BX����
�����a)����f���/�-�<c9��:%YP�
�^f���A������%=�#I�)Lz�����.bF�d!>���������E[z+QR�}����\$j��\z
�	\_�S�r���U���������:��<����d+��'����X9��;{�%UY�<-�� gl�X#�'ZX�q��\|�	�3��bs������>m@B^�e;��!q��4w��T$K�y���<���J����������m_&������Z�Ng8���
�b�TLj�����m	�����eS��L	~�?���'���=A��0��d�qd{�'
jH`��n�,�����P8��
/����Aa=�+�����������z��!�N�(��IJ$���D��7 X����k����e�{���q1�����j�l�E����OJN9o"�Y�-�15s���$5/�|O����l�F4������R��!O�������-�K��I�iT�q��6�=Bi������'l�W��i�0��<����ob�����q�)X�_P�W��J�y�&��z����}����;�����������:��oQ��N&���I��d�!c�������qo&�<,`�ifd���������zJ��
����x(���K���!�:a���Hl�gx� �6g�F�,i'%��v�sQ�W�(;��X�P�7��Vo�����=z^�%~�_������1������X��_�IX����?;���b�A�w���"��r�J����
!`��e�E7�Y����H�;X����K��������i5�^�^x���e�6*rp�U��V%������mb8�5*cF&���k���~�}�L]�z��u��?���s��?�r��++T�dE����%��+�V���������y<��������m���?��t���f.���A���! ��5:��� ���"�0�(%4���$���w`X���b�F�Vt�1u���MH���~�D�a����H���j��
�?�\�o �;�3L�Y�����������u�8��^�������*k[|	|��%�
I������]������������T��N������������!/(|���
�j��I��W�;W��
7���?���=�% ��������F���)��A�6���&PG�h����~��:��~����'�q�N�����z���'���5��������W��)����~���>C#��o�l��0H��2]���k.ID��2���
����Z+��_�5k��'/_DG�V����������'P�O����~�jg^Y+be~��������L@��s�9X���&0���ls'j��~p����]uf��H}<��-�������p���Wf���K������A����)q���NB1{y�\�#�G�����xr��{,~���1�9��\��"k(�����������������v-���Zu��?�{���-!���-��b�,u�FoK��|���B����"ZY��k?��;�������<�����g������p����3_?"�(�lv+;�����x+.o�q��\_���2�����Ym V�U�i�7
����{��h8�^�����"����*�L�]�'W�.�fz3jq��I��t�L���K������34��*�o��������R�t|�	g���5�:�@�C�Hv�.Zi�Fp����89��4'���3��Z9�����oP�	����^�b{hz��W�@��n��n�&~�M�T������Q�=," �5,�C|{��>L${��J'�E~��Q�m=�T�[�b��*6��AQ	�`�A|����|���]N���%�'�JNzKaw�*��^D���	�`
�r&��S�k���5�b���&j�W\d5� ��Q��f�'JT�����bX��'���QW���Y�]\w��&;�L���m ���B�b�T��lL���nk�d<����!�w��j�^)A '�.t�����f�A��_8�V�,��O�����Ri�2�UkL�������>�rC�0�U�)`������G�-�z?&�^ ����fp��a�%zB�))�$�8�����"��m������jWM�]~�O�"�9O�*�	�u����]�����5HB6��g ;��	1{����C5���Hv�:Tk��a� �r�56zN@_m�4��u�t7h3F	A���i�E�=$�o��� Ei}������b^L��]AFF��
�MrM��<�Db����
(�j���=�>��5�Q\!�
�����Vp��#!lm��0��d7��vIz���2���u�8l��u\I�'�|��y���z^�X����"�@������8�����n�}+��p�"�@DL�q{
o��u0�M�\�P8
��
+�}�h�%u�
Pf�,���Gy�A�c���
nP�@�;�s���T��#��������Z��
i�C��K!�����|�WT���<��o\��yQ8��j_��n��Wb��%[�Ki���s}��c���?�!�=8�����R�.���2q�y�C���h��!�G����@4�|���
�S���.���*l�-PF/"�i�JC3�b?��io5��������Kt���u|�Y��T)�H�.���5����8��8}|
o��j�b�,L�Y8��h��=�������X���>&���FS���?��,"",��
���i�����\�Gy������E�\Y�fnd�Kg�M��$3��sz3��� =��#q
}�w�������&^,���5eS�
�I�h�F���+���m�u���
����>z�\�+�sP��BXq��V�:��2"7����������.�G����C'��J5���7X9�>�~�=;�L�8 ��� �_�N0����dI�h!��K@�	�s�e���\BJ�nBGW"������hxTfo���c�
�$��I@�����f���N�����}H��u�;b�7�P�&�]�A���(���z)�zmW����K���\���,2@�&b�A�����c�}9;K�R��$2B�G^�%�Aq�<��OT�=�����vK�&@v��U�����3w���\����n*r��(hru�B�8�|JG��=����c��3G#���N����+1bq"S0z���"Z[�*5������%�90f+�#V5)�		�����2��e�4AG���g�O���No��%�
����(���l�BK���=\��A�P#��jc�|*��d���,q0����,D��N�t�����K���x8��'��tuo������`�&X�-�X|���X��U���jNb��������d�W�d�\���D�h?=@�fa+��*�y�.��-��q����]G��<��xB%I�F�M��N3b������1��<`�����i��Aa�h[(��F�C�7�M<�D�'O��A��������a1C
h��,&)���t��[j����vn>;���z����m��DO$����)&:�O��Q��Oq�b�����O�`H|�=J�~�������Y����?��:�V�,��(A�Nf5�)_�H���������& b7�h���C63J���Q���\
����'tN!�
nt���C:Z4TM�(,Q�"���C����Jl��U�(�6�9��G�1*2��E���C�5	4y/��g(�	�`*
J�:���E�7�&IUR��/����|�|�=�����[}��:���&��������w1��������<O{�s��!K(-����/��JU��	�c�o�c!�C<OW!���8��z(� �����i����������NV�rh@�AG��x�����G������^fsB��!`k#��y�N�P-:5juaA^�w&���o���F�m <�����
��o��,]�.ac1rB�����=JU\����������C��(vu�|NH�58R�g7Y����D�����
�������k�A.K��>.r!��#�r����[er�0����v���m��s�Bc&��}�g����'$k
dr�<��-����l�G��g����uX���g�����- d����}q:c��NR��4�'7��F�*�V2dM�u��-���<����2i���T�d�?i���kw��(]k���M�w&��C���v����Bm�����,��:�����'��fu�������I;mKj��'wL�=Ly��h[��z*�K������#tmV]��X�I��X�(�ll��������	*sR�*<���*��b�6�l��@L�zw��6�&d�4����M�<97�)+�uD
��DeJY�kpw���s�sk7O)���>�E�����}���2B���AV���$��If��������K�r<�#���e��D������e�����r'��Y�!mW6�}
�P�n�'L��J;C���:U�&x��2�-���<6S����I���:?������do����y1���ll���k���Mh��QB��K�zE���PY�X1P�@ui����q��E+0o��
�Z�'�B�7��gv�u��QW������Y��2�PfA�6Ba��$xi����a�b*ooW�U��`j�F�
U�?0���Q�����4�����U��>���������E[�#dl���b{�Z������{���-
�1���G�M<��U����{�:��Z�"�)E�������|�%����@��c�z��^eRL��J��g���z�~��Q��	��M������n�j��X��[;�%-��5A��H��g��L>;�Q��n���O�7OU!��U����L��A��f��O��R94�F���K��������kv�����/*oa�
+X^���AJ����9�x��S�Q^��:��ka&1��3���e����-�f�
-���.a��U�VE[���;P �h�Kw{m
g	~��~�_\$�+\�Z���%��2�R�x����@��(�?�s�4�����o.(��WX|7�Q�2�d#��k�F�������]�^�U�,-9cg*B�Y[j5-8g�~3T�	���W����W)R�v����<����lG9g����o0�����`��5`�����M���rR{�^�w�s���u�{M�C�Y�)sT3��0�_���z�<\��$��Mb����o��EI5�ooQ������6Y��j���3
?�i�p������p(��8�9a�v�1	�:0�7��w����q�����:�S��^�~$����u���C�?�9cy�Z��6o����o����
"b}S��rcB�
��5K��)
u30�".owd'w��|���l����:
Y��w�N�������cN	������.H t4�3�DCe�v�"@o��wg�F�xg�T�rymn�-if�aR�b{[Yj�X���a���d�.����=� &W��������Q<���?����h>KO�;Z�H�J��|qZ�*��R6f2�?�U ���17�d����%!�<G��P?i�F��k��1J����tkM���Lm�:��~�g����.�i�fMYh��2]w������6����br|c��6L���������t��\&�q���n�v��/p��+UD[�U{�����p�Bq�A�1������3���ukd�,onlK�7;���E<������_�j?c����1�~�W�����)U����,	8�`����R�X��z����w���)�2��7�����������ra������l������@�P���DUEk��������I����=��OU�x��R�Qr�;<�S�lo4NTh��E1��#@����&`Gn����$��U2�N�t���S�sbb�18NLY�(S�L������(�(9���T4x	g��`~E���|s�H�p��TSq,$��HN���i�>��l��U�����[�Uq�� x�X�5��LHx~m�G�`8ob����{����N���;j��6hX@m����w1-�����:
�Iq��+�����55H��G�0�����E�%F�!=�x��mB�QM�4���NA	qv���@[y,�#(�������2���P�}\��U(��#����o`�Su0J���u|�l�>8>h��>rg�i ����	q��)^E\T��uezm�}B����@X�����`1��o2=O@5q����5g[U��ahLLU��t'S�K����E%:�.Fag�oz���"����������
�x�P�TF��9
9��x�U�Y�rw��������}y9�I8g9�3��\8�]�dDZ����s���_�%�P��xjEy<I_�F��p�D��7���>H;�E#�V�>�K�-�J���E��xSA�����pw��-���(�m����<����aQ#�U��0ST|SoB��N���Ya��/��"m�����u��B;4�H��2�~���jTy��@
�t��p�l
��+qQ�h�R��W�?�V��D��;ryg��'����	�0��Y
J����&�A���&C`���O���LM*��
&D"�F�\���q�������tz�8V>��7Q�X(B��`��)(�+JL�hV�����-$V��d�����K���XL�����?(W)h#����f�����0~XiK]�l�AG�;��|x�����k��U�� ���I�tw"*d�JN���
�k�TQ��S�bN��Js����E=�!oSj������;��A4�:_�8���I���X
�*��
+/1,)��=�s�p�]U�*������/&l���<*o�rR��d��_a>^Q��y0u�<~n�b]� L&J 2W*)Bs*�P]���t�g����p��J�fE'��.���{Z��9��K��y����3J�3�B8���-j|Xae���IbPV$ L-�R!��9w��]���y�������	T�%����y�2�.�;�{@5�kQ�x��R�
��O0nc�:�.��
E��{XZ�M��QT�h7���"J"����
�uH��(�36��H���La����s^�/_$���A�/���*��,x�y���:��������b������L���������I#�c���A���������l��������38?��q�9Zv$(�%$���,���t�_v��CFV2eth �0a���	X��kZ��_���Z�����z�c�������Bm�>B��&���AA�H��������i
;�Kd�*x�B�)B�cH2�9�)%���F�ox3�B�c����Q/�+��-/����I�Ps��3��X{������a�Z��NU����_.�2Zc1�{A��wkO(�x@?�I����W�,���"�vI��L,�T����a.�� �k��g�X'2ZoF���#C'���TLV���'��Q�#��iE	��ez�y�(�*�*��~���\�N��M�s*�����lm[Q1�]T�pa^���U�9����'.��� ����%����HaVl����"�)������Hq��J���i�<�#{,�����n���g��E�&���Xj�����L��8�M)�U�5�/��JE1 \qMo���2�t�� ����D(L��_F�<�\�4�+//�<��&^Y�Bug��9�\��6��R^�h��k����$�q�Z;�������g�/"�`0����cZs���w�,3�t-��X�5G�F���6�RU��QPC�r��� ����8F�����d�Dv�Sk �,&JGU&D�jpbP3D3�������ep9pJ(���MN`
���V��A(+w]�w�����$��#n�R��E��.���}a*��Y?�%&
���p�Q���W�$3�F�F�U=�e2�V�Ea����o�K�9x���Lr������,]�p�yYF=1g?����YZ�NN�b����=��h����3��~}��~g�r����e&�}�z����\"3Y,)��4��v�:�	>�!���b����������ww�cF_�����6o�e�x���t�Ye
��70��������5����^����|j��� c/���E��I�N�|2�]e�)^��}A��u.a]��Sbi��1v�c�j��g`�Lge�-�E�3L%����� \�����Pn'�K*RL ^R'9������P$R0/�-�J
������J0'�y�i�����3�MBD��6'$g��a*Q*|�ep+��)��M�SY[+�iz��K�������U�����4}�M�-�V���`ref/������������Z��#���By��_��G���,g^�6]�����'NfI9�=D�M�n}��lB�%IV�|d���`Ao
���E9S2$a�}U�����=��n�'�/��f�u#�'���RD��4e��6TW "
�3�s�4�����X�@v���,$s�u	�@��fb�BE�(��Rj:�����	O��N�2~����i��=N��^#�"�e�Q�rv���{"��r4u� w#�3��T0E�resm�������|��e���?{�m�UtG��>Q�D8���05c��T4����jL�}��L�5�AO�tN����Vk0�=7 g��
�i�#j�����+l�����(�B��4
����l�����V��de���h�n�A/5�C1��U���<�k�X���r�W/�@=�3'��(�FH��A�a�vg� �e�R�2?(�dQ���/KfSDR��/�����S�t�BY���Z�lf�3CR�3��\KNM���X��\�.
m�����������j�����f����[�w�0��������������k�������nds�&��Tp����V���?�np9�����z�I�F+;�aE���}��c������ns	��2/5,@iu���@(����'�h��1��R@�x�:�?8*����[9�������Y
�=na���YD��G�"@������J�A�r����������%���Ay:DqMg=^������;��Ry�<�9�sj� �ZCa��)��Q�3�U7��Ja/W�$�]�8:,jeW��UD�����kW�����[���]�����TV��O*������Z<yv%Lz�,��.#�z\�e0n(�?(���
\���������Z�U�j�M�@���������a������`�2�K�8P���`�Bp�����Uy9��FP��y�"�GP��@�P���BLy�&�8'B9���Yi�Q��`o��7oK��`7�=M��C�}��o��� RM��!�lo��5���`O��-�I��U4�.q5����t����Ro��"lU��a���R��������[�q(-,��L������ST���o�oDp�~X?�����N�)����B�[��G������C��������/g��O�����"mt�3y����.�K�[�����%���Q%"���ov��Ax�sK���J�h8R���f���Bm�
m@��]d�2�.A��S��Cy����Q����B�������I��.B��~2���>>��-����  u���c��!6�g�$����q]#��^���7iq��a��VI~��)�=�Y����\����4
� ����'"Yn���,Q��T3��1��/-�^F��-���R�����_C���u��kg��f��},����?�����V����g���=Rpx�@v�s/�'��i)�w�O����f�R��2��Q�6��mz�z�b9�������>U4�};=��CB��I����h�����4G`�`^���XN�V/4�fdp�G��I�:u��"L����En�I�����'������'y�����k��d����e%��n}U�;%T{I�Kys�D�NQL����x�aVm��o�Idy�G�t�����Z�V#�Z��$��7����������#Z��5�V��*�Dqy��}��Fo��WU�����d1[��d?�UfeKJ��
d��MA1�BG3Y '4If�j�>z���s?�\O�#��,AT�]���(�iL]6HZJ��A7���h�%-�n�����f�.W�J�V���0�2��"�(�}B�� E��h���w���-Jz[���6b����J���W����J���h��;�����W;��B{J7�"If>�P��&����#q�g*���JY��3"�{ZF�Q���a��f�CG	��t&r���S=�p:�F��5Z�E���8���Z�":��3��1����C�Onu�w~���:�;>���]��Ns�mzr��i%�Hf�L��!�
F�"�03������39)$h��a~	�1�lR������49�����~e&�]��3}��a����BP�J�N�B��"���qu	S��%&$:H��V�����~^�;zU?���>���&��a�}�{_�{�c����?�53Z�p��X�"���w�E���j����c��<���-rC�I��+V����h�VmA���?����_�����=��7	�$���.qs�\1z���{l]��Om�q�ql"�i�<-z�+�X�zPt��x8���t]������X]����U�A������G��M�1X��xb�'8a���	�I��4���X;I���Yt<�P�o�@F��4H;Wx����W��.�)�Wyi��=N	����Xh��l	k��A"�����U��_��"*7��,����g3�{(1"�t^�#��/A�~w�jV+Q@����~�W��]�6�U�S��M�{6l�b����fC��!���1os�-���SNo�����DM��=1\��9&�rE�~
�������u<�u���%�H��~o��3N�����Tj�@�c�h>���C��r1�0��}���rh)�O���3.�&g���t7@i������jZ�t���mJ�%�%�*���{�����-
?�C�ts�"����t�};1��2��TB�����*;�j��ig����8SN����������{���?���@9Z�m��b�������z����gM�P��=��(���@�ul%&��Y����x7�y�3��\��t<@��7q/pB������aK�m����HiU]�Nh�.����s����IV�2�e#���;"	�w������p2���Q����=�I8f��W�H�~c+�A��)7��=����8�9�������.:!�g��T��i����i�#�����v����-/1T���������+W�^�0����9�:F��y2�UG�Q�-�"�~E�;b*=K�3Q�������	/�[M�O�@�O��TR$�[�ce���!�{�A*�K�"��u��t���
C������7�h�������uzo�`���QX�J9Xe��,��Z����C��~�F�P����"�b���u���oDpD�4KP��SW�'� B��z����m��y������p����k���<�����~�mc
���P����b*�O,�$������������p&k����f�x�r8��N��9'i��)����z��������0kfg`�M\nc�����o�Avnq�*lZ��T���6c��k��i���7�c����=N��"����H����������b��5��R��U��r�c�L#�;s�����|�g$��&�Y}f->�����~�m�#Z[3�w-m�|��><9v�*_�k������+AzL�!������rK����$�?�c&����dn��W���H���)�H�e�e<)�*�U�������K�x�����"$�'��f���_e)V������QZ�H�u����nvM S��'h$���4Z5�@d@�X���-�h�G��0w}��H���lST7q.�W�65��W��XU�'��s.o���=s�)^��$6�q�m�7�er��h�����R��e�YC���'��;�����`���!_{��k��F�L�1e�%Z4����H��F�o�Ux�1Nct��(@h_�3���g1�$���}���=�����r,(E�O`E Hn��r,"dE����x��$&�e� �u�c��<��05�_l+���2�>@�Q������ (�b������)�o����
�H�.J��uo����D��B�E�TG���Fpj�F��9��%����79�x�D��S���98�d�Z��v�}(2i
�3:y^�3�"Tr���G(2�
�0��#�����P;���"�9�MtR�\�5����	76	%��eC'Y<�����O���6����@���B ��d4(�-�������a�])|��,r�I���$`��gzS2k0�__����8�6����:���4����u��LZ��*��� w��O�>���m���������3�|�	!sB2��#��������`c��]�)�=����-��f�oZ) �����:�K�_�E33�9�7�ad D-!���>�t5������u�D�����	�_]1��H{`	e�!n�H���no�x�p2V���k6�����k���0�>��[�v(J�C4+z��I���c�N�&.:�nI��|2�u�I�?����_yW�h`2��CA�����\����UBXR[f�2�N�~t[PZ��e�b)��Ln����.�u����D���%��&j������{�}��/����6Nq���L5Y-="�N�=\��8
�$�V�����X�p�-{3��0:�<z��.c'@����`��< #��f���@<�q-��O19Z�mk�4��+�&nR��$��}�����K���Tiz����������z��VV�j�]��#L���D�c�8�� ��u����Aek�!v �%O#���<y~8G��n
��@]�OP����]�u���T���3���-D�b�h�+d���[����_��_�7���E���_$V�M�n����"�{�
BP�"��Mu��/9�������1O��o��/M8��'qrvIa,�U��k�6�����?w8�����JV^I�HYm���J��Q��r�t�w��7�H��*V�]�^C��S�uh�,�v��x^ I�c(�M&�����D:�#+H)��#����������vt
���	��`.�,:QV~��[��rt$���_oox�Fm.w�������[����w<�G=���n���M��&����S}$g���pX����Y@L�,�DY��"���G�a��Z�>qR�!��n��}�=<�CsZq���r��<�
�=!�@=�$N*'y���|�I�2�<-W�4�����/�����b����sT�b�C2D����}a�Gsl��,�vRE�?�z��i��
���Ez���HSJY�i^�0OD�N	O���M���Q�����/����q������nP���&6���'�&l!���	_���1pV�[9�3:����*[}D7J����vB�^��X���'�f��7�/\����8�m��F����]B�|U�@���$�L�'{RJ�hd�P�$��7<Y�)J�n�	?vZ$Q����]���	���
.tP�k��NjA�hBv��6���mt�c%���������2�������>���X2����e��Ko2
��e<=�^�#��B3����z��[r�'G�dB������2��y�����!�EgR�)�F""��i���j�By���]���!b�E��iv9m�[Mr-���3Y���*�h�����n'�������R�h���E���H��@�0m+��b�5v��=7@y��7�R�eFl��p��g���fQ�:8�����2���P��#!%�U9�q���;��&-�:� ���"$�����L�&1-��dZ��4�cY.�S!���LE��S���l/F�)��l���Fx��"�@���9��6l��^��U�^nUB�9G����,-+��\��'e0��S��%��ah�7���;�c��O�s����Sfq���Y�M�C>+��ZI�@^�����_�4��S��s�I��M��J�T/�/Y�f��Q�q��Uk4�g�F����������4��@q�%[���=����h&�L�,�������QY����[�����&{C�e��f����v�w�KquJ�B��v�&����"����v����o7��4�{S)���GaR}7�:>��pn�	S���l�wC�Y��z��]��b�������V���U�	�y������h�3r�������D����5!��F�����g���]�/���Nk8U7#:�0��&L�,��4��Z0�����|����,G����Q������/��Wc*�B�J�_����\�k?��;��a���=��������>C�z������?"�6���X/��WW7�7�����������h��-<Z^^��
H��`�d�[�L��,(���mhD�����Q�������7�+
�|�|[?����Ma�������d��� ��� 3�m���<�-�1a�R��XT�,�������`(�
v����$�C��8�V����u��g��"z�u�~����]7{�u��T
�c�k�����JC�p��J���0x;�0O����&&��(&��_,xiKU�k�P-�yOu<�q�V��������N�p�%"��/-��U��*����6J��hy��Y�P�lw)t4'}�'9����K����v(���_k��s�����+��sw�-�O��Cq�w�NA=C��O����XI�Q��FI�NT�D��N:.�G�F�vt�
�a?,Vl�
j�����i����K���Z���q�\�P�ry}�T�PO��CY|�������P��*fU�k����<�(2��-u�x����Ra3�E(�/ ]s�t�9�3��1�����X��;���z������
���r����|�1sG�CyH,�)����M����5�<��
$[�]N�1���J�a;G�y�$��&SI3�T�	������!��vu{�<�Q�fB1�����S~�P@�`�?c��O�����g&Tl�T���^�S��lg�S�����"���KE�=Sd��K73����+�.c���>���g�}y3���Z�������#p�������jd��/)������a�:����tKp���|���Wf��#u�a��l���v�')�}����p��A����=����9��C:���DvU��V��y���� �_2�*�s�[|���_����s8�7���p��+_�`��{9�
��(����pf��\�T � �`��������[[wVu[����
�D��I����:ak�4����g%�����~c/F�y���������$3���-�m�e�y���g�9������T3��4u}�6��bP��Q�*�uke'N�����\^��Q���q6���9�	�K��������r:����5=u����u���{!F�4q������������Wfs������O
�8�����ke�E(�y�b?�_e��l����/���z�*�x�p�k����zD�	��)���"������T���P��@U�l���3����^�]����J�Dh�)��i�`�N��%����q�V������d��#O+�y�4��>�|�,���f�T�����)m����i4���k���i�R� �XX�����!}�K|n:S
��-9=�l��	'��8?�x�A!�l���W#��{�*�l�����$�$���jG�f�LK@+��	���s��5J���tGr��xYQ]�����&���Sm=0jK���\yKIT����d�%i�~�)�3�z"�DKI��&6&�+����������d�U	���|�`4R���y7JQY<�$�Rm.��i�QR��)����j�
�����x4�u��&1h����H�_�l�d����H��l�������HV�]8�	%e��;��������Yn�����?9W��[w2���-��a�<��>�aX����
�TJF��V�-#�<����e'�[���m6+9��U�7��m�W7�J){bz��;���,[j8i�J��3-w����g��������r������)m��N�(����Ku:w��H��Rt���������@'��,��&h�2�M�������������]�\-�zg�U�AY�c4W������2�zn4��f�K=�!�.�^���6��2g��������)�|��bf*��n��M�l���Uf������"'�����K�,N��N��
�g������XWME��C�p���b���[Uf2�t���S�]�`%�(�B�F�Jkg��f�����dG:�/����i��x9N���j��	a6�^Q��H;�l#dgc(	'?���}�4���@�3s?��������[��_k�;�t�����
�g����YJ��g�����U`�����
��C,��B=�k����w���*n��t���a��!�V]g�q{��vF���
)�#2(�?�3Sa^���9�EYf���c�������6�@#>Q��(�UM�GA7u�Vc���D��vy��F@��������z��K��)��[�M4���Ss�:wT/��
�*U���H�L5��X@�-s������f�|�v��x�!�
��|]d�!����9,�**����%Gmy��j���I��S�I���c��%��I���"���1�vw3�+[g����0��<��o@n�,m����Avf6�%�$�l�v�T�^���7�������	O�l�7�zn7y��lWJ�����W�����5�C��}!e1�Xri&��:r,�	����g-I��)Z`�,�G������;ehf�Yp��mn����33�|�����|;mBI�f�)Svb�v��{��_E�6V-�(�^_V��e���m"�r�\Z��@,����&�L���VV�%��I��W�JC+�D�E^���]�1��e�2�$wu���C]�5e"���j�^C O�i��v�����d�����V����g�,�1�<�0����#�38;9i�"�>�������h����
����N��`l=� r�u2g+���LFv�6��!�d�����W��h�t�+l(��Fb�����}ms��W�(�[��E��n����;7p�%p���}���u�� ��G�����u�]��D��:����#q���=����'��J�����J����}��k�%��y��+��@����Dh��9���	�1L�5��<:�k��g�n��p
�r)r����D����}����B���������.�&�@���.\�����DP�����Y@%Z���=Gr������;|<�3��9���J2s���BG��P����C�r{"���B4W�M�4�qyW�?9'�����u�T
�������������n�����T��y�Td+89y��y����z�N��G���d
�d�j��y�iO�0'�F����/9#��r�N�0o�{������������io0�@��.������_^�'W�-X����5�������A&^~j���6�C\V	��-2mA�n|AQI0<���:��5��QoP8j��*z%|K(���?��
I
Sz���-m��Z��uh/>�%�R.Jt'�X�ycLv�c�hxq��]����*/P����=J	�fWl������9�/��������0�I$������r����������q���[�2�.]��.�va������.66�4jc�����Ph�h���Td��|��u#�f��M�p,��R�]����b�v�K����}�*l#�<�)	�a&��z>��G�����-A��Zw1���2'm����8Et���f���(gpz^8���D�����Q����-u,�!��_��/��
��H��&�[?"B���D�a+*A��UqW�7�u~�#�a�����,!������������I���]�E ��R���E�����������j"���
��{�����p<^�P������T'xF0�0��kTTD���	OE�h��,�Nf�_���&�^yi���&G/�����(��CEa�E�k�M���i��N��eg���*;����� 6Y['�DtO��r������:loP��9Gm���a2���t8��B]��������9���%b�o�W�f��
]����s�AQ� l��67G�n/K/c��@����.f>2p�!��p�7Q������8������i/^���Q����5��uK����=�?SF�I���J�*{�[���T>Z�?�=vSFs�f>a��-��>`w�������<i}�G��?Q[�r1y�
��w��	&P^�-+�y�o8ux�*K��B)�~90����1����#����y�d�*eD	���e�W�;[���J��2KU�HmZ� ��
�2R2��������s����s=88�D�{���H����@���$�q�* iHL=��3�~���t�,�D�i��~�c�C�s��O����T���v�lj/��N�s���!��b��9����O�����������V�{�l�i�7!K��T�(�-��'�����b,�V}�#�V|�����E�������@S��tD:��QMx~zZP�V&�@g�(m�T��� 'I�W�eL�P9�����9��7��`�����7U)[����"A�)/���b�'z�)1s}4����;B���S��#0Gr�U/>�Q<�%�3%�9��~��|8m�cWW�eR'R���0������pB{��{L�R�	�������Mx^����e��7�TR	_�9�l�g��b:�"u�VuOO�����C�aw���z��M?�Wsa��[�xs-^]�w�������Z����R�G��
�6�Qy6&���Q���� �>�J���>��^���c�Q2�����+��lP��
z�� a�%��A��w��"������X���;a�zNP2U��,�Z���
��%����s$6��X02U�B����e��5��mL�����}TK#i�S���O:���<G�t#��>WH��rF���Y]u�O������`0�����`?���Oqc�����c��������^N��2��G�Ic��������x��L�"jM0[V�D�q�I���X������:c��%��)��$V�^����;�x~���:\��.\�W�(O���}?zd
������/��A��9�$��$�����^x��x�����X���D�C�.X�R��J�E|S�/���Ho�6�������j��������������������+/�R-"�i����c����:d:�oQ^���������wEp�)ZV�R���T�;����O@~
e2�T*[%�Dr��P\�$�h�����g�J��
�H�8��f��]]bz�jQ!�q
0@%y gC�{����9U*�Ry�9�K��CS2��S�C����f'z�����sS�(�1*i$�-���c���(+�(�W������g�F��YC���4�n�"�NX�@O���-����oQ���Ql�W���"����D ��f:�
����=��
���_���"�9��'�3�;�]T��Kx10b1p�9x��@��M��������x������������+��_>Y��l�0�����+}�H9����i��c23�����2��j�d�����V+P	 ���b��hV�d����]���I�d�B����x�x�������)�QH|D��j�3(�!�0Xx�v��i�="&z.�fjO�{A��S�����8f��-�-�cG�t
�	��r���!l��;����,"e FVp���������$u�\<Q�>��X����Qey��[�S�������_�_VG��x����,��\{*������e�J�O�,0��K�q����p��B��dU��k.��l�8���w���<����:���Pj�h_���l���a��\l�nsKAV�&"��VrL�M >��l�K�
n:s�;��BE�(���u���,RE�j]��=`*@5t����1&��FNt��g<��L��N����*����������V�t:,*����"n5�3'�6ct�a�x������@�����z�������C���
nyy��j�%�\P	b��F��8��F1z� np{�)'�tX�V�yFyu5n�c��ol>��*�+7> %o����7�^)i��c;A�H+��,�JcV4 �V����C��-���~�=-|��o����"�hq�K%E��v���Lp\�
P�byMvr�f7P�p�p:~��(��e�D�3�N�D	5#78�+q�na��U|*%���Hg�y��1����q�eut���N����J���a�����=*��`�.�x���N��^���)���������a����}��2�l�xR8I��~>gy�MV_�����������)BC5��qo8�Mo��`�d�At��	���>[��u?L,���������m�$:��K��y:F� }}u��������ZS�J	'��Yg����n��h�S��^S�S�}���8�!����#��Vi)������:��C���zc�LJ������w�\��6�],��?y7�8~`~�P���"~��J����A���M�T���?�0�P�Q��=mw����kk:~�����BT�W��]�o�s���=CF�>����{�h�Mr�SozEh����;9����fw��l]l��v������<��
R�#mU����Ru=ZF��
�\;��
���X�~�K,��*���QB��k��|sy�I��r��2��?4���d����GCn�!�f��\�_������!�����k7�������<���+�����=��}A1����r���)%T�"6�zNU������%-��/�g��>�C0��q-2\%^Z��!e����z���-�St5�N���Sx��.��%EE1~qL��a�x������~0S���/�ct����� w���
t�k������������b���E��x�$!MV���}��'���;�=�B�A��>lZ�}{�2�|��#GFrWB�'Q���'1C�6���������*;
��}��\�~
`w����d��h��v��U0��Z��z�'c����)��)�%�����ERd��Y�$p��
�V%�����|�(?�� f�|��)�oM�=&��CTY1����]V����A2�KF$�~|�d��bb��9�Mo��	?GmR�R���n�pq��ZR��B����{���w����&�+��]��ft�&:�5��qvq�ud���l���cE��)�&�x#1$��N�A#s�
��}�����N8��,�!��G���p���%����\��8QS�1��n:{����kMzt�K��X�%]FEg������&���k���?W�����������:�&��R��mm��~�Z�	v2�a?�0�3�����0�c�3����t�w�\W��T��8��p<��q�U���Xr� �&.�k7�~��1'�U?�/��D�GP�=�t8���X��#������3��(c�P,����[�����$������b�;L��NIN����#MDv�MH�z`��<$�/��qm�~����H�Oz}��%���E�����!k�D�{�1���@�q���&*�/��a��:���s��{����l� Mb�(-�L
���^��]�KF���o�]�q��C����O0~��0���C�}�9�z82b��g}t��Jt-��<I8��@���/7�_?���g��E��d� `5�;��HJ��PxL���v4�����X���
<�&���W.�;�[/�79]�0�t���W����V���>F��d�S`�����t\�z���y����#C��}��N��&�3�s��{���m����J�#Qkc���8�04��|�Y�*��*��Zwj��@XB��X.��2J�R>	�6f"���hm�%�1Y\�L����
�G3I���wj�::]�M�V��v�DO�a���)��*N�f��q�*������'����pt����,��Sj��6���_R���L}@�P��l�H�I��7�h�8]�3#I��J`��8T��<A���M��,(����(��oX'�)��&:�Ns����=�P
��:�0v�ABJ#�!����r;�k6�8RYn��!�p�L�It�I���eR���~�X�C�q��������������8��(�8�
-n�������U!m�$Ft:����F����aY��y����}������}�����=7+���y�����OD�����D��"!���g�x�v?���>���!�Hh��E�x��ma!�����l��������/��E�y��eg��xvmp;�N��k�O[f6$	�g�1���R�]{�5�$�rJ��+=���S���|�;���p��B�={jb�wq�����(TYi%O������*c=����x�^h��vQO��I���[�2������W����C�Oi.T"�%��q'�����cG>}��`�g����	hQ����q���������a��o�	8z/�����{�3�@4���L��������:`�<��Z*����f�;s�����1���!��� �������E�!oG�A�y�@n!�"�g.�T~0[D��f�:����rGsg��������0���I����Q<^a�g����F�I�Y�r
�6l^���o��f/�k����HK��7i�Q���L��uH����P�������{��Q�Hl�b���o<�������)}3�l-�=	���'��>L�s�P�3��)w^�� �i�����B�f�ts{��w����;�T.b�����Y�S����c���yT�.�?�,�a#�DY6;}��6g<>)k������v�2�$AT���c�[Gv`
<Q1����Y������jlR]��NV�`Q\K���B�
.���S�SL��D�������W(�r�M���E:l���p��Q3��Y��L���"q�4'�R�����a0�Z��<8��*#��
���>��dA����K
�v��v���2���|>��g������q�g��Py�b0��~�5=�!���g�>\���
���?�W3#i�]�`'�����+�F��h4��� ��#�}65�"zC����KU���'�{a��6��F�����jI9�Q��nd+��q���q~��$��E��Q�=m�8�&$�*���A��Y,$HM��O�g�=qR��(Q�gF.��Oz�8�A����D"�7����'y���(�7*���lf��Q�L����A�\��5��Q�#D&�����+ �q�B��73�l.����r�����7�z�C��&*(c:�R��� �H������5�'�
���R������I��H"U� �u���&����}�$�e:�PY�%KJ��*2��z
s��_��6+,��e$Q��@���q��n&�K�7�"|��7�J��t�H,|���eiJg7�H�I3w�� :q
�&>�F���b�AG�MAt����!�6H/�7�;�+]�")sj"����8f�+q�@����'��\���w������(�^�gx��]���H�E�=P��>^aT>�/{�����������@4d(���S���������A
�h��	6L��x�d�;�
�R���7��)W��	�,�M�����0���XI���c��o��7�
�L���<���A��(��f��n�js{��4��j�Z	A���{x�_xS�e�Y����&~0^�!���@
��	���/vz�Y�z>�4�4&�S'��u3�6������U��u�D?=���E/���]�8�
�@��QV��``����{�pV)*�����hQF7�D�HFe���2���[�O�-�.��_��x��2�
R�����i��=x��?>���t�������W�6�.��Q�i5p"���e����O��J<�+N����L����V+����~,�#Q���o�]v3�mC����A8��%��Y��h��l��S9�o������x5�wKiN���^����\M��������m�D;������O���uu���?
�
�u���V���:���^1U�C�%����I�#��3Lc|��!�=f��v�����������K�x0����b�%t�H���Dc���N�KB��2(,,��k|�����(=�Jze��&	:�~w�.�z����Fnd�1��>T�o�2@�Fp��"|�RM�B��k|�u�j$i�~yku�zF�Pq^�2�]��'�f��*L�V��4�}��t/�	Bc#,�g�����A(p������A<� j��c^�EU�R>lL�6D����H�D����Q'���015,{�'��vS�C���R)x�$�fx^��'��!����#q����E�F�e,R��������1�!�t��y��~qp�~�25�P�t�S^UT��Fs!8�����n�6 ��V����(yI���:���%
?���|�V��4�S���ET����+tKk,�:G��hs�(�����M������� ���8$�r
�����TEn��������gX���k��D������XSAQ���`�'6��s	y�	��t�>�g��6XH}��o��Cu
����u]�nWGo�G/���u��z�o�hc��:pv��{p�}vpz����n����XiB�T��M��=�i[V��T���//o��9<2���2	:(��d���3�'����-�+a��L`g���c;��������wa:t)�N�?�
�]�&��T��D��J�^���R�<*/�[��i�����HJ�������>�I�	�"�[�RL<���b��j��"9�U����-��M��_L�VWP�����h��+='���?�������o�Pg�0���.u��s����I%>/���TJ
9��)��n��lF��$y�V@��m�rZQ����?�g~�
��:�*������"��NT:���Q���2�����
 f�����&G�N(��(ErM����]���B��r����R�"�cj��5��5fj��:B�y'h
���!0�8)
Y���_���j��s5�.d���)��74�bgi��>�iX3���,�:�O>���x^�f�E)��jW���W��*b
�����$�G�EN"�R�fB�q���U-InQ��J*�B&,rZ�7���gz����Q/"q�N���r�H���"��s�Pzx�0��1�'Lx$��HT�9�&��g�y��O�%V���s�5�&SC����"��S���%r]�P?A�*�qs_�h&��I4G�u��D�TQ��l!��`S�]��%.�a�mSL�]���,IX������6�9%b5�D�w+�;���������v�Bu��)Q���*��Y����\_��jX��t
lk&����0��	���=�����tNe��&����J��#0�<@���42���G�.#�30��~�2�R��+�U�4UQQi�h��c��:BOz���a��#�;r�+�Tr�*@�r���E�����%f����h�U$���
B�����pn���RV��;���,�����f\�����6O&m(���R$O�\������p����xD���]����Fj+����+9��{w���>Yy������YG��{c��������u����z�[7����K�����d58�s`-��bA�P6|u�v_�$O�p���!��!�����J�p������0^FI���`�DmX[�[E�lDM�A9�yE�Pg�����eG�:�]�T�]8y��aA�y��_pA���pl������~�����,W��;�a�p�[I����L�����������=|����v��1_*c\EZ�D�+��c�Zy��<����1�|�.�a�f�x����Fn\�i�	�
�G�c�5!9���<_�rjMH��rj�M��R��/%c�6���|�)���P�rG�L������k����h�H�fu!1��i�����@�jV+]bCz"��������A���[�2�Ft�idz9&
��
:	�\�^+��7�����C ��g��k+z5�B������)h�%�]�7�B�������@��'�{�*�-���|����J&�KQh�t�����A n�?���"�������u�����{�O�'{�{����i��~�����5�U	Z|U
��6��QA�����q��O�0b�(�k�$��
X��
 �2��[���q��)
��j���Kb#�E��{u"9Q��'9R\�k��E4��X�Hj"P������$B����(S�PIs��@G[�FL���w`>�:����+�a��O���
=�J�|Z5��B_P�1(�0j;S���O~95�!��f�����QZ�[>��^_�����i�l�U+�cGX�Ad.�T�����".B	��9��I0S�n8�uG��� h�Zb�
�>�J%�A�B�Q
-��
����������T�RII����D.  `��p�T���L��\���0�.|������������
�M�/����U����X�x{��L���ug�N�!�3�!�^��������P��Y����Xa��\�R��Z"+�7:3������p��h"�8w�B
U�L�y���,	��B��B�1�)�!$>��x�����������y<�o�.!f��I�
#ydQ��U��X6�#U
�kB��de�}gL6!��kn��n����"��n��K�;�����!��a�����9�F��p�I8S���:�X�q�
�����6���Z$"�D�,=��
-Q�-
�!A
4����-TF��J���O��V�/'��=��USLGbM��}v��?��/1���X�`*^�&|��V�)��@rP�P��K7�C��"���*C8�Q�0���S�@Z��pb
-���z���;�����"��dn*�(����#t���Bd����]�+�����P����"�P��M�U%9'��)�-�P�����,y�����J�'���N��Y�+L����������GO+5
eW�����6X�V�4Y�����'�&������PIg��1�����r|^���Y&��MY`�YAe���������&�PM�da�.jV;p#�#+��v��0�H�|��_l}��Q�*�\|`4�0��e�(l�,- ��p[���GBD����]H���<6*���~TG;��B����K�BVr�4����h����N�YU�
I1��H��e���D4�jl��
 ��f�].U���a�L�����M�s�X=������l"U�2��\ ����*����-Y����s:�����"�J��Z��.���xX������D�[�E���r��������)S0�
��s$�l�����j�,J������+r���X�W�":_��
�y8���
Z���N�o$+��\nD}m��m��%�p�B%���*N!`�;�$�bJ����o��#DNN�Vo���p�����)����v������J��V�I�"a�Z�f�'���9��<�;��J�<���j�v����9�;Z�Z��g�`_�&(�KK��g�nl�]a���8a�dS�� K�2f�+�h��*;�d���#@��E����Gc?N�:���;���c��d���m�Z��XLc�3oUv���J,�qA�|���p.h�u1"�C9���^J�Z���a�ycc�������Lm�`B���B5�B$�A�hr!6�4s���+B+����o��~��{�a��� �*r)]A$@�/�Z�R��5��QB�� jh!�E�m=�c���T&a��S��]�n�Z��
r�;��#��-y�(9y���0�w�����>A5f�9T��*u�b��0H��p�V`���H3���������+�%�a�3�uwcs��z����hW$�3���w�/��gSV�W�+���K9S�����p������soh���#&L;�b>�(���|��D�| K|�~����<O��R�v�f��	��]s�N������?�]i�z��r�B��i?�.���@~O�����b^��bX^���EI=	��Pm���x~reL��"��t�#[]��$0� ��!����*#f.M�@=���dQ1t�������R��ZZ&��Nk��fc�v5��c���y�
�\9�XW�r��@���qT7V�)]���Z�pA��A���i���/w%��N�SV,�T������r=�����H�&�(j%jCb����d�P|xJ����O���X6>,��\����#�S�����[�(1��khW����z��M7��Go�=�{������y_Ii��i�6����/��ee���c<��H+(t��,����T������@�QW����'~����I�r����E����:f\���:��#�x��X��v��U�"�A6-a�RL�k�d�rq��p�������#2�+y&T������������F��o<�n|���hH�����V���E1v��=mu��\|�����I�z�
G�x���<-+�!K�6_��8�eS)��	~i6j���Ef������"'�%�*O�\����[�B�S��`"�4-������Kr����]�4x-���f�����2G��/P�y������=������g���8
����_5�j'\��;\�5���F�N��C�obA4&��:O	VCq
e7�K;���|�A�J��FL\�%��$;I��;_�!s���A$&�3��������g�R���u���0O�d8��%���6�x��=�����#f��cH�;9�92�!���������������O�_qRU5�WK�� ����67
b�����|*m���sX3�P�'���Y��D;��E����f��x�3O�c����_�7yw �N
g����3��j~��W�`�����*��va���H}N�Y!_s���Z4���@�����pEWlL�U,�7U���K�QiW�C����.�N��[P�"0����fp���Ql)��Z�Kcxi0`B:��[���k2�
�E���g�:����'g7]A�s���P�#?g������U����iP�~#�p�e��+��<�@��Lw`|g�.��J�N�������j������s���I���$]�e\wm����1:I<��o���.a$}7��E{)�w>���X�.�i�-��+�:���V$H�~�/k�4�R������j�Z���z��sp�n�"A]g	��0o���a:�;�����.����V�������4|o�?'2��<�D%Za0��fb������Y5���c�z�Y��p�fW���o8�����i���r���K��l��V��-��!,L��n�2�	V���#����r^�	��aN~=��(���q�X�,��uV���bU__���(T^_��J�?�Fa��2��E�|C%bB�������9��L��z"4�fc3:�;�Yv�o,4.4z��^�&#��G��l� �z��*qm8S�D"z#z����Rn^(G�����o�H�����J������{��Sm���d(5?��,�����:"?�������?l�����C��X���+������Q�-V��"R��F�"�~�N�����?�>=>j���V��W������*vH�0�#h=��_��4E+z$<�BR]hi�y�	���e����h�5��%��
6�NDE�����2�����88�4����_a�F^���b��z�V����w8�S���(}������BP��������t��u�#�(��ds�A�V�e��[��Y�9z��h'X����f�xz���E���2�k��QS�J��2��i����q�{��
[�R.���B[s���������=�c#D�`($4Ff�u���-��,��t��fi�
j�y[�<�2�����I��T=�tr1a��V�:Z_m�VV�R�b���*���P�H�X�-1���y��l?|��w�t�p�62G������G�~kH!z"����\�X2�!/��%v������r�����V1"cQ�RQ��xSA���k*o����� ��2�F���0�L	-jO$Z[�$��I�/�B9-�$���|�t����\f���X
���J���qBY��o���"���/�/gR�[YD������F�k	�l{Q�R��f*���c��4�,6zZ��NvB�K�'�1��f8��4�(��kU%�/����W>��ct��|�[��d4"�U@����&��5
fs]�w"����rs����t����D*�OI���E��yx �d���)k���uJ����[8�����e1b���/����������+������J��+7��L��E!��..
�B��21Ano�v�-���B���5U�q���'>��8r����p���y����o���6mq��V��:
���Fk��D�M��8;��X�!�2���u_`�d�^����2�
g�����8���������D{5V2��`��v��-����|�w�E�=*t9������n��a^[N�%J����,d��/E�������c�����K�1	���x�����^�!��K��ye���� ���p����pj��*��K�"�����^�I��K��;j�>{F*qJs&������'�,f.f��!��1C��7��=��O�RV�!����d��C?�:����O���*[��$����$�t�{1����*-Q�i���\^�-q���
����kN�^�|-����Pb6���S#�-��2�
���
�j�i�����Nw���pC<U�)���(���o�'�S>��(�_.\n��W���T��=�<u�V'C�D����n��Uk����]����c�u?d��q����?�
������6��e��(m����@����[�J$��e�|un=�BA�e�T%a7���b����;i������'����?� sn ��CI,�2@y����,����W����cX������=,k��)_�v��GV�J�K�D��K<���/��!J�����BH�����������o��7�o����35j�����O`���OMA��!W��d�w�<�g����H\B0��P�Ke��u�u	Tw8�j�U�te��N������"���~x�5I��b�{\'���p���"���w��B��J���f���>�F�N"���'���j:y����m��p4�A4J������]�Y��#�����	)7 �ve��I���2����N���/����y�(��:c��u?��1��������L*Q
���p�[DsV�:����G�5���x0U�����L�������o�
G���Gsb�OL-c�wq�E�wLP�`%�(�����
��G����������&W#���4��?����������rT�+��e�Pr�yA0�����.F��.��p��Y*{m���7
8N�=>A!^�+�|������9��U^�������.b�Kx3�y�|�Y��x�{����O�$��UQ�*�g3@���X�1,�w� f��q�7��Wp�E�
�9Dn1j�������z���,"d��8#��2��a����o�������r2���wz�E��Fm`I�{b�=U��N�X)���b�}6v��,"���)G"�*�=1o����/��� ��)�|��iw��U����
�����8&���aP5�d6�R�L�����*�-V���q�0S��G}���;�P���|������������+���53�P�q���b�Sb u{W<�r�4�|�X�&N���n�	vW���C'��"|��j���5a���C�@I6��%=YX(���K#�y���A��s�G�,�������~�!J���3��a���i���!���=}�h������jl<�$��,l�����&���|	�������k���8Qk
P�w�	��9��+���,:V�%F�4s~9��y����t�����//�28X����������3���O���<���?�OB�,Xb��%�|^J�{�7��b��L"������^����	zT^��5��!��drI �#MnRK�C�m���
�*�qZ�3$-0��k�G�����Ey2�q����O�������\/����������C����
����9�����;{�c��$����i,���+�MO��pI���M�Z�}iK�r�tsQ�O�&�b<�������z�g���3��Z	T��
��39;�+��<����'������@���UM�f(�,M�h�Hi���i��H%�G'��#���?a��+yw&S��=���4Z\M=�j>K�L��4KMuaK�Di�������������Yj����T3,5�%Zj�K��T�h���m����4�KuY����_r%<^�PQ�lP�VN��

�SC�����-���E���.�x�Y(�p8�g�;�������������J3��%nm��F3���[�}�%	��.�N��&�?IU�X���e���;Y�HKe�,~�E�-�M�r��b{FB�h�PPB��"�����br���'�eZ^�����TS���Us������d/�{��).��Z�K6.����Z-k_�`���p)�2W�3����+�\��m���u�~FB����7�_s�\�1xecDT�Dr)[���;l�
���x"l"l�%BL����
E���;8�l�����:eMY���[���|�~t�}S�@���>7[��w8P�*�#^p��#��^��{W=����L���%g��?Td��
��~}t�x{�����i7+~P#y���p����>����@@�����vpkWA�\���\�$0�=TdlV�n4�l��7��J-�	��m��V]��D����D��=Jtt��z���^����X'r�^_��B�j9&��^5��C�������P>���������J"�*�]���TR�%���A�����s���P�~���P���(�P�}�4N�u��S��Ng����z��R�F�����e����&�y��9������jr���c�"D��$�������2�����
#2_���uKQ��~���5�1��-�zx�������g���=��s�/�2�B�q��MQWD�=��e�R����<^��+����.��ah4����U+��c�X��w,��-�@���������3���KF����-���c��v�������-V�YN?�7�����E`���"���x�>z�<��i���� ���������6YVclC�<6��&�,�b&��d(�6�3�s%�<�v�h�D�����O-���V����,����k!rF�D�dz+zz*
��,���}��xM:i]7�9�Y��(O�k9���C����B�}{�����Wm/�(�8�*��[rf5����$H���?��l������5&W��c9Y/�R;�f��W����1p�b?]����*���Eho�'E���������0)!���)Y:g�W��i�Z��\��N��`����G�^��i��C^B��E�XQ����~Z�����~]�In6�����K�5��0���Y����mB�CLR�%F1������gGm����<e�O�Gt��l�!�++�J,pT��}	=x�~���m�bX���J��K������?I���#0�[8���B8@�Np�I��"��2����l7r��O�"�rCSO���O��.�',���,[lX����l���m]��10���XG��2KTZ���}'�{����=ow��b[����7_���W%�����e��$���)�/��g��7��=��c��:����9SmR���g�y"q�g�e��d��8���f�(�]�)���T� Y�6����%�c��h�US�J
����z�F��f^�$�!|���}&����%3�	�#O������"/��w�dB���tZ��("!���^�sa�9;BG�������u����v�T���b��0�����q���
����y���9���"K�H�	5�V�Z)jg�BM"h�b����/��=�8���%����v���<F�^0�����nN#vv}���x��W.�b#�!��q��An����6DX��(�#���C$h.���@J7�v���{T�C�e"�����#��i���q5q15�G���S�c(�*T3�"H9���3-�Ge�3z%��Jy�a�f-g��a|gm����a*�Vy��)�z8��b� ������������n�	���?K$P5�t�m�w�������d��DSsk��d!���V��G���n�"V�����Y^%	�G���/#�rG�"�r�oqA;�'�
�~J`���
���N�a����A����5ZH����*��wve���6��:�;�fC�uO5��L�Z�d��M?���`�����k�Bx������s�\>)5�mr�D~���2��o�LxS�t���T��@��[	M}��K/�0-JSG����U��T��������
Z�wj�DN+n�yE��P|���������5�a\t�o���C:t`������l�+t)f�N?��%�&��7�D�����
D)6�8�h��4���ld'�c���c�wR��
��:����t8d�6�{h�4��00��U�� �7LB���E�E����$_������@3���m��� �Y��
����)o>���[o�X�K��[R�J5iW����`J
�n���9�}���.�:D��I�x2�a�'%
�Q��[��a�HU��{��95'"^1������f����L�:���S�X/�R8��0
"�(�mm�����;�����U�EK�JZ��������x���b�<H/��#,:hC5�����Z>���)L}k��7z��X�"�j�M�m��p)�����;�x����[�vI��9\���^��6�����2&}���a)���E^���I,,�0��;�9���1��'Jho�c,��������0�m���yU�Z���/��L�:S���4ld�w:�O��e�{V.5��x�\IJp���X+�,���\+�\��~#�c2����'�nJ��������x�2G�#�J��x�3H�v������T6F9q�f��j(�����d��K�
�S�����[�����(����L��J3g�w�]���
�E��x:l� 0�1A��_�v ZN��t�,G,���`<��R����p
����LV��`���
�e��8�e�]<V���E���HIM�r)��2:�&~��i��M�4�%�6�{?�H��(��"Q��`�F���\��9�p��G�zg��2V��(�(�
��{U����m����e���Z����@��ps����m��*�G���B������;�}8n�7�B{�yA1f�2]��jj����647�X�$�!��A�	&:^K�����,I��>i_�+
�o5DM���/b;��a�s�.}�n
�6b��w��k�O���P�6�����e�Z"_�)��~7���Ejj:O����h����=��_2������.CY8TV&&|��,���z�K���F�b���2_�
�7[�-���7����t1�($*�&�� �;M������IT��'�B������	����+������������+R���?�$�"��#����?����P�&N1Z��B�P�&�dA�"��.B

t��m������X�������F<B9j.��S�����;���#'ZXxj,X���0��#��y(1/!Y;����S9�q��(b���/$���O��H�8=r�U���J=�x���1�E��:��#C����%��`%kS�y�bg%�ymHL$p����}�!q�a�����fU�p�e�����X�`W�TXo���a�2�%���h�40?���
�cI��d1J��k���u�G� ,H�[�CQcF�<�x+]B��fB��4�XO!�_�4��� w��-G��#�"�[b���8`�����������q#������q1|�S ���F.��|��6�_^ ���&b��Z����B���W+L���
��L�������S�}>��5��C��s�ouv4� ]��F�rV*��7A��Z�Lr�/|%t)%)��*t&/b�.y�*����"��C?��#�ZL�������8�]��{�C��X���>��k���v�j�U	u��
��w7�&d>��������u����A ���T���C�,����2O�]�|��5� ���NoD0� 2�t�'��b����	�|���0�%d�C�$�A���,bkb��
�Q�r��,L���o��@�;2��W�6�p�B%��T�%Kx\Y���.�hMQhLT��������41L�g1+=c'��M��$���<O�pj(���<�y��Y�M�:E
�1MhQ�M�D�z\��d�'�
M5���{�i�"'�q���L����C'�X���������,����(��]�N�1�����Nw���;��U�An�o#�#��]Dh'm��&����T�~������z��j��IW��g�� ��-6�8��j��i�a��2���cu�F��E��]r�3�X�T��=�������lb��?D�L,J����/�W�����>�0�R�W�w��Q
���hG	^��)�K���R��4b��$�R����U}��-�_SCL4��w2�_k���s4��)8_�]�Z������gb�$%8G�`�&��t�@t���4�7���$���&X����B��z��	����7:�n�v�E�Qd��`t�l,�uk@����o	 /R�V=�Fr����H�U1�	�^a2uA�WD�"���'��*�tX�4z�*A��c��"�Z��gEQ�
$��K�&���p�M;+��������*�=��z����q���q��S���e���������@�a��LlC;nh��������cJ'f��r`��D��z�@N�k���H&6��5D"���A�	�2���5f;���	�\
K�����A%���X��VE��N�Y�D5��v`����h���������T�%B�5��L"����b�+(2���R9�y�����
v�0^8��R���j�E�R���fm�)t2������N�+`[z��������XY�PYf��~r#��pH�l��wH���!_+N��CK����W�[�"QE��p���,\��0[�A�%1�q����t4�!���[�-���=�!����pY�������+�|*)�3��"��?�����o��E�XN�R��>�RY<��=6�q�O'A���������y������D&��sD����*:��2H�Hi�f�s����6�����������������=w�3�!$D��q���7�_^�
U��BZL�9�Fb���L���- do	��������w-D}W9gj�UD+�b���'j�C>��eE��5�0����Q� ���h,)�@�����^��i#���899>������p�-�2��������W��OV�)��of�!�����:��m/L'����Q�����2&�t
��e������/o����)���fS:��c`\�	M�FYS)�^mv)Wo���/%;�'�L��2U������m�M)�$�Rd��L�W���r��7'���sJl��)y�l��� ����_���K�G��;���y�!�2'�����\���(W}���O5��##�|2����e�K�6i.���x�:2���Fa����`.Jb
�2�'���f.������ZR���K^��8T�e�ZMXgP������\�d�Z��+Y�ca��AbPe������jI�)�sh�
�3cL������h�G�U����P�!Ff����Q��F��Ff"Np�VF��������>
��h��C9|�IrOC���<��1W���p��� ��H�XT��2j�By?N�6����H�H��#�ZT�A�p�)�R
�g�1��;���/i%!A�����k��������zW�G��8;�Lm��@��GHk�y8f�0��Lg�o�����lC!��N@�	��n����0���T||��(u���`�����Xcm>$���^$�3�}���
"F'5�pH�����m��H�PqH2R��2~��\-����k�*�Z�V��=�������~H
���.M�{�+��>��C��H���=V�t
�b�C
V�"���q<q�O~��8k?���{gg���Y����7�"�xA|[I�b�a��`�*�{��hcxC�-�Jy >��^C������[���<��������[.�������S�*�2�����%����g�p��2P����h�������;�kJ�$UL�F�|�q^&����)�:*S��������TG�&����G����������4uLx�I?����Q�cx��Q��to+�?+�WTVH(�����9�����:W���|���i��K�o���~$���p#Q�=�ct����E��7��"]���/��R�<Wn��������/���/�{''�S�y����8���j�+�|���3JFj�j8	#� �`a��+�"@@���0��ug�Px�|�b��;�+�� -k����I�k����r��k,���k�\u�[l�{�jC��Yn�[EV��p�%��xK'*���KL�C�-�'&qMi[��#�V�\k�+�N�x�6�BQ3)��~")���&
E�MO7t�{`��������i��/NCs�=��%T��|��Y������g��<�y6��"��^��RRQ�p0�������2��L?W�2��4�Fb��x�>=��3�)��
�sp�qs�HH#��4�,[�Lk�fZ9��^���<�<;<�[�?�����G��"}��r�����#�?�����wjm\X��Y^��^g��w�2,>9;�O�t�����4���3��5�b���$Z��659'jr��9������dk���}����a"]���h�(V�����W�L��U�E�;M�{ �
��Y��T)2|�B��������*���U/>����q��z
��1���~H����������.s��C���W�n�>�;�Z�����a}�x����7|�R��4#�}8�+���>g��_�a����c�rQ���t&]�G���,�C�,�Auv���`U�`��+>g�r�B�R�\*5��n�`�u����6�p	��1�����\����������GP������,��E����RWJ���"�l"��<�X�j����`x~���/�3�=
��G���]�����7�=���S���q�W����qz��{^��;����0���l�����m�A�Z��*����9�����
�
	���KHu�_��p��?�/���Z!P�k*�&&���2d��fp�q������t��'�s�?��m������=8���8����/G�[���3>�OT����3�<mu��������Ud�/�x?��������	�;z
��;����3h��m� *�������m���F~���VDh�Z�{���g���)��k���_m����
e��Y����G}�������1�����0�oU���
'`|@
��F��Y�;�vz�B�x>�k�V�K����W��%�M6"_����Np2W���.�����+��������%��
����������9�Og��"����j$+�G_�/�F�x���j=�&�C�$����[{�B�.m���9j����E���go&�|X@�y���V2��]]��������;�.}�w��4xW����,�/��LlQT�����Pe	e>��z��if�yV(B���E���d����nR��A��!^4�
n2��h �d��v�6��������Z�8�m�^������i9b�b��E�:����R�{P�!�����Q�G4zX��XtJh[��ka�
���={����@f�
��i2�:g�K�>���*�B������Y�V��l����l�WQ�u+�P'�X�*S���/H��RN5�m����~������l8�������6�1�`��Bi�J���u*��V��X���aH����u�����r��Do�����n�5r�����V� �O�������?���H�� ������g�U�����k*�����=	��n��TR�����l���	��u67����z�o��~��J* �RIEY��f��c�0�\+��a�$�
z���K����-ACb8�A���3��������vBT�d��7��u0|��2��������O��&��=X�Wc|I�"�E�wz]Y$�"d�N���fOCZ_���
��/_������;�7�����s-�o�^�����^}��������>��}U~Uy����W������_=y��W��U������W�W�^?X������W���W�J�V������������c�a����s �A���B Z���N���y�������(���?�vo?��U^W�%���(|��h0�����d������}���k�Y�(�@�������x]�9��Q�����f��J����{����W7�/|��Qs0�*P�����������x��0D��Zc>�v�B�k]��������0�+NjN�W�^�l��`��`^:�I�J,��
�W������@��`�����������B�z���r��~2�S��� ������@7R�<�����?�Xkq���M?
�qc��G1�n?�*}z�Z�� (7*w3���L�������gO��7��S��v��vk�^:�Y���s���8�G�u����Y�������+%��4�.��w)M�K�c4��z<#���|�w|/�Q9*��������o���o�k����V3����k������t�<{U�CQJ�I/eR`1�q���d@��xi�Q
�\0-�&�W���`g.��0=<��W��{0z��F6j8��x��H�����P\��3��T��%L�����>��WZ��a��,�&��bE�
I�%�w�;�Q*#/xc���R@\u�Ai�P����A��D�-4�m�����'r�>J7e�{����U����VV�8$���."�+Ve�d�S��hc�x��c_��
L.����l�#g��wn?���m%e��[�>��L8�������N M!���_��������T
�'S),������*)v��m�Tl���,G��7*�lY�iYq%Pv�&zl%��P1]��a�3�r8�l9���:�t]�C�����g��0�M�i���a�4��q�o��5��B��
/��
�VVJ��tg��;�����xg��S'x7��wM��T����o�`	oG�
��N���f�< w6ti0������3���*��U�L��@T�
�S3^H���V�B[W�nhc�
+,��x1�0N��QL �����h�������9,]�������D{�VFX�Z}���z}�|�����c����Y��r0���j���
5&����'����z�0t4Q�� �������]�b>�]�4h�,��Q�H�lu�1�|��f����hr~B�?)����{^�z|u,�F�~���G���W���r�m�L�/�F�>���B�������7}�O���_a�����o �&Q�V��xk��	t��i�
�3�~�1���$����s�E�����wTT2�Nw��b���jO~�<5y>�S�����j�f]�S�g ��~(��������\�W p)|Y�������1�����������&�&Nc	}������9N�&�K&�����;��B�#]8�E=��?z������~������`�����;��8����;x��S�SK��J�rG\�:�;��:(��n3�1����@��7~���.�Y1��z��
uF��\�����U�`^�o>X��(G�!�������	/;%�k8�L�pU+�X����dbx�<��e`�n�09�vZ$@���<^�����N�v�����h����{C+��,�I�S�6�K���:��x�2������F��!��6�g���B�e��� {e
F&�EhU6�E����{Tq����_{\1�X�U���F�R�[b��8��no&�k�N�H6T�����d�i4��a��������N�i������v��|)[c���dz�	�@������:[�,:P����a�n�?)iW�$X������>����i�*N~�1(�)(/:��MPQ�KId�I��tE�����o�2�R�l&�xG9���\�gJn��Wb�<D��KY��T���H
Z����^��5���>t�Z���7\/=~AY�G&��j&��hw���8=����T��u�]N�-F"+0�=���G���9!���T�.b�c������_�L����Pz�S�a�Q%�l��/���������D�/�j�M�X".��EY}�1t�|�����JZK�XXJ+����CV+����"i�k
'/�0��	��������6�b�}�3��G�W�Iv@�{,:�x��(=���n8��?�lM>�1�u!:G.�I8|>����}��?��|p|*�3I�<K	���+	��������������I���
��5J�S��m0�W�%J�4GST1o[p+�X#P#'tt/k����B��BN���^6T�	[��
�u�-����K,��Q1����0������17c�X�+��R���Q�n��v�m����J�]�����#���������0A{Z
��
����BU���e����0��BYT^��SF	��T/���%Hl5���J#���
���uh�6��G������I,�4�1�����@VX��"&R�(
e��	�-�Y��1�p����j����� ���4�CM��y�L�=gk�	v���\\'k��.|C�G�.�v��;��� q^.�S�fG��	������=B��`��;�#!G����*/����I���X*^��(��`2�h����+�d>�t���80�a�8�b-�:
q>T/���FT�6�G1N��������%!dg'���:����Nc[t-���p�L�N.������W���f�:����P����X���q����}��$!}]X����6��l�F�d?����
83�ill�~d~f�B��tU8,u���pPo����pM�<��[
I"�������	f��	kX��j��y
�S�H/U�� nO���(����%��L�"�(��Y7m(��'m{i��/�
��� �^
����@�]���B�[��N��Q�W�4*����B*�5V����<�ed��"��5����b����p�����_u����}��<3j|f�����)h]����d���mE�{b������}P���*4�c�<$��z���+)b�A5y?�J�`����;��[H���"
���S�P\r�deEI�����\�i�9$U,�U�u�c*�zM�1fOAJl���7�00U+/���������Q#����p�E�� ��������N�,V�aR'r�@��h���J�="A��)��V[��sH�J����*&�C�C�W����Y5���K�h2yt�R��i�����|8~���M�xz��C�72`�����Q�?z�@"S�qaW������=�h���/����luO��z���u��pk[�R%�pv%yr|E�:�9��,>,xe��N�x�/v~��O�fz���B.TDe�Jf:>H�C�2O���	��9����(I/�~�1�}x���NV�����dz�����3��o�gJ[cF���
>�����^�[�z��s�_�F���?�M�~k�MYEy?�����b����Q��C��8W�#�s!,��(�����m�������$��\����B��3���VDj�� �<O��%1�`���Ap"CT�\��!�F�&�lN"�n@��.�9����<�^�l2�y���J�6K]��F�R������d�S�������'���hp+	��(�w����"lneU%�,���%�a�Z�Vb�.�m�h��B���[s6`��n����)H��i����c:u'�@Gl��o��#�{��a�f_�����M~<{�Xg��~�j��)�d���:��Y	1��5��v�m���+���I�y1�O��YA3F�>�'�1P{�����W*\t�>/F)���f�F��������E�(����g�13��E'�a�����QBV�v�����=�f���� (K�y���D4}��}��%�iU
JW��:��e��j�6�csb�jX��%�+��K�R����3tF��C��]g
m���3��������uF7_)i$3 �����V�������9i�-i/K$����o�CG��d��fG��x����Zt�n����T�y���0U�"�"_k*'iV
8����Y��Hf�+�/��)�,�ts��e4mB1UR��cP�oNN���o��}$W����+��X>��r� ������G5��V���E"�=a
:��g�RUyE��������$���k8VV/��r�p�O_����X���N����I+��E#�!6�o���8z��b�2�F����,�cN�Eb4��!�klT1�
��TjcL���H���7V�[��JY�x���m�Q�#6m�M�����#f.V-�������w;�fM�v|cB��;YhP�S�<X��FWx���+�hs�w�j����[����i(>u���d�����!��c�.�����>���F��EE�?�N��j2���x[5�	�km���"�������)U�b@{(vc0a�[#�VR,���']I��l[>�+�������(��GiVp�������l�Tp���7��?vtphYi�cZ�;Y���
��d��Ka����Y.
�o�Ko]����8�7����A<�HW-��c(�@���J���K gz��/u{��|�6���<G���g��#�b�JT���(V9�����)�n��O������vG�GJ/M����w6������_�/G�������������PW%���E���\�6O�rC�����s�vx�P���
(�(�Jv`���c��3�oC
Fu�!t,��L�Q�!�E�	�3M:6�t����Y�Vl(�jElh
!��W�[`]�7B��h;�0�����C��g�_~���C���;�����)���v���r�����<����,8l5�}�@�]�3��� �D�?P?�7kvt��5w�����D�8J�b>�� �'�hC���_P�H�p��NT6�.�G����-1�W����7��"�?�%���:YW*�RI��z�K��0��4�(���K�ni��vF�Qng�����������C}�'���]���
|v��%\��j7�n-��(�j,�$�F0s���� ������GZ�hc{�9?�������`s#O�#JZ�#���Hw[
Mf��:����v|~� �2�7��o&�S�~_Bv��g \� u-���?Z���D�
f�h��l�?�@ ���1���!��pn���Mn]<5kg��E��A9�����QD>akC�-�j��SDv���F���
Z��~�
_(�f��U�����J@���_>�������.
"=��x�2�����^��0q����;t"^/O��I{���_&���g���u&S�Zu:���������
v������0rEW�Vd����7[��C�3?x	��Jn�=9m���a��!�rp��l��u�\6��"B�mb0�jsc�D�G�����we�	�o��t���L��+e���5��'~=I�.]f�[�'�d���ZQ6���J��Y��6[f-g��5����pt����?{���
p#��)��:YK��\�$�{������%�[�`��C������?R��������oW��������p0�e�QI�!e�-	&wGy���p\���B8H�
��1������V���lo	���T��y
()IW�MZ�����i)�49�`=�B��{���5�1P�'���U���9[}�����r��RW<����bTd������Z�W�?��"��?��p"�z����F0m]�b5lY�V}����Q�b$�������f51�������6Z�f��lZ����PW'4d�{����0�@�vR���/��MC���u[��e�=<G�� ��8V���[��<�b}��t��uO��~��� ���z���������(;����7�������:}
>��H���,��e�P���2E�KMy�����������R���KZ�������<yLd����Mm��;�\���;^���p�h<6��
1���s)��+�%%*u3XQ��I����-��3kG��
�n%k�(h�!O�m��[Eg�|��������������O4
a��Fyn���g>9�����u�:�$��p:����h�1�i�?U����������v��#"�wo.G]�M	Z���prz���<��Y��.��-\M'�^�������f#��������n��������.
���Lj��;����
���]�AZs����@=L��
�)*[����+_��J�&-{�O7�el�����el�+�����g��'�����^���D#�X#��O���O{|�����u�yV#��������8���
g�e|F�������M.q�C�!7��oY�d.��;�n5��n6��V|vg
�xfQT�Z�N�
����?���������y)��	[E"�'�x�2�2>8o���*�1�<��v��x���(���T�W�2Oh�K��S��6����RC��d���i��]�D''����������L�^.2�&P/��zE��Bv�d�Q�#���I�,V�����Bf�L\c��)v�o>\Axk��y#z��mb��� c�����0��11�v�����M�p��&�0��#��2D�N�z)�@~s�m��z��r�v,�[�To��|�;�
���N<c��)���.������?���E����7�C��Ml�������9���H�����Ko�����aMB��������d8VO���*�w�����3W4�3f�����-�M�l5gg���*v��gu�~:�m{?U�`KWm�����.��|���5�@QO�r���n���;������t���\�M�H�j��q��1�
�6/�F#�$��a@�9�g�&#D>h���?*%��<d7^�P�)�'v\"��j47b����a�!^���zk��i�~W�w���Jbe��o:[�������<i��u.��z�hv
X��Q�Xgd+Ld+�v�M<�v!�v
3D��y1�/Q�S�0��\_^~��a��4�!������&L�-���uT��u��V3;j0�v#�p�0eN;������7��]�X�����4��&�m�-����O+h����8b1n���A�\R��t�8?�t)!���M��j��G�����V^��7���c�xd1�=����?;�v��������y?%�v��]�!����B���h+fln3n4�/&��]��"Pk�;�
AL��T|l������

�B��,H�Ap���(�J���V����z9�����h���6D��	�����������L��������|/@Jb��`���L����?���������d��K�d&��?��d�~��X�{q�u
�^zW���f�����@[{`.=�+mnZ�	M���m+6�w{CZ���l����9y�+��A@�(x���;�70�W�(��������$S���Dol�0,�d�I�=�xL��X�c��K4�|�@Z�G�Xq!������`��{�f�im�+��O�{h
��E���F+Y1�}I&�^����M�7���~��y�2V�bs3�/��E�k[i{�$��h��f�$kL�N�F6����pl��������]
����K�(ev����o���Dc?���6+BQ���r�����T3�
�8O���F>���R�l��#V��f�*9��&����X��Q�q8��Q���7���@�0���N}��+b����q&����F�x��������)� ��
4���
4��a���1���W6�x����L3�����3�p��Q���lQ�����'sfYj�R�sSM��l5��z��K�k���4o���6��a��	��I��#���F���IL0�I��f�eL\S,���M)��������Ws������h���?���Xh�`-���G�#�)Hb�Xc1g7~�����
�������6�
GA��"w�ls��`d"��������(i�C��D�+62	�S����q�����a�)u��&��������	�^|���c��[X4���Ab���M�S/�J�Wp�D�,�i/��V:��@J�1����%
iI�:�p�w?��0&��v[���m�C���f���,w��;��p���>�i��@���3�3�8v�\l�P�m����������I����G����t�(q������������6v�5�b}���-�b�Y����%���������D}+��B=])�s�������������$OS.�0����W��|
���� E5�	"b�A�	�!����9����8��H4�-��Yl������PU7/J�F��g�?e'�\��w��V�	��.p9���������&(ZwS�6Sw,�������yz������P�iq	�6������|�����=G{/��P>����A����w$u�_l�����!j�]k��]�oS��`��<���n�}���4�����q|������
�Lf������j��X���_s]�@�����9K	qKo��:��7�u��=��2
F�����5��&5:�y����{�������}���0Fd8�_���p����R����� 3�|z&Q�����G@����|8�=c~��4����O�G�E�������1(��xu�
����^�E�80��Jq�V�q�C��7^�z�N�A���:s��*�?��T]<�z�V�����/GO��H#5����'�{G���!������U��h�zrZ*�{l��>_�8j�]��K��{�9=��t�����{��i��xs��onl�66��L�Q�Xw"��r�'��G|����S����O"�1	3z���VD��0�!������<^A����@�������CP2�����)���������Y�dk���z�p�^+"	��\yS�RI�S������"�AD\+���z����<-�)�0�3'�f^^Sy��9�S��%yKGNg��F�����r2��,��
����0QY���BM��A�����&�Py�*2�i�+Sa��]1�� ����hT�M��"��"�:�����H�]�K�1T��<��i�������a0 �����R`����+�n2I�p�����q��o|Y���6������9��(��������:#Z
�eTB�u�5��y��&� ���Iu���y��BME9���o.b���Nf�����)���/�_�?���,�H/��\^M���WstE�M��a?(���&`������SZ�v�&���S�?}���|������#�c�Vx�0o�*E�&������D�	�T�tL������
���d;��������Z�~����6�����/��Zp[+g��
@�)[5�����7��F�&��B�<[����ZboS�����L!#�/�9A�m���������`�j�`�S�q��L>l�J����2k�
kW���Z�A�nG�?�J�������juk��`��ak>:D{\��q:����&�0W�@�g'��`W����W�E��p�xip��6�l-��_�Uv*!�����^�^w��F����*�(�zjk�T����N��n�d�I�u�B��%���`��Q��*������@B�_�������`��
@tQ�
46M�����t�cNv�k�	��S�\����S���koT\�$�*L�}��
���=�'�:�����|�u]zo}P�������[��3���s���y6!���2�����bU�C��p�s�x��NC%�AY��/p>������H�0��5Y������<���.�|V>�H�?CF��xTc|s�0w5����'#�0O@1��H���Ge=C0�yFJD�����7���D�#����@e�1��!�KP�P������=~���PwO��e�/��X:.|9W�G$��8����f����r(2��|P�Ma�����9����"�|�_m������i m6����|�������������bY;���{d��M��g'fN:w����}��6�����/�����?��g���w�����u;�%�����5#fg��3���n`��a�{���������dvV�J~������v("frg�����N3��5��������2�\M���1�7��50|�Fh���M�|N��>)j<�Y�5�C�;qX^�O./�n��=`�DN�������O����CjV��:��m��c������{��d��L�1�wGj�3&�*K�Uz��5��~���o��)��D��2
�$km6q��_�u,f��txq!T�!�U��w��+V
e?�<Gh������W-\��E�n�_O`�� Z9��u����j�O>??��f�~q�����i�l4��h��V��X��4[� ��<���������0]����,�z9h�&$*|�HD���|�K�jX<������9�M'����%L���g�~�2��6B�#�	���-SF���i������{�����Z��PcDm!�����X�����k�3���(��(����E���(�}�c�@V�n�#P�����Qb��J:�����o0Y�"�����ZK �B�fh����b�Da����hD�!r21T�}�� iN�0v�h4��xB�#�#'��S�?:H�H�1q�Q����K����)��}z|��n�������j�&w����y������]0Q�4���>�H9(;Vsk�	������
.��@�	B��	��N y�LTg�����g5H���@�������X>"at��V"��zLWo������:��aHH� y�d)����V&W�n�Q;4ij��FL%8��0UV��5��`H��Ib3�?�������U.d�7�Y~!�����X�Lt��G
+�+;��$��PB&��Y����b��o`�������I�89��e�u��y@������)��$FAWZL���vw��7��HP/1y�k��`9�--JO����5Z�����N#��atU���0����y�h�t�s=az*1���&���J��u��
��k29���5[��:3\��Kaf�R8D����S�jE��o]���z������+����%ot=�:��r��+�J�9sc��v�,���-�	�nc=S
��Y�������2P�R!p#�$"%�T#	�W��H��N
[�����u.�\���opx��xf�vx��������\*��;��!��J���.��e��V��s�jm�q�U4~_c'�[�x(:X�CY������NxED����!dAX��2��kD��l��~�QT��
���>�B���'�,cP�%G�����@!ea�?fj[����Ar�������	�sx��"�������Y+���2&�����M���?'�������9���1F
�P�C$V`��;6�=j��e������t��ukv�*��R�s�d�6'5�'� m����L�����e�2,R&k�qRH��l�3>Z[��$VVN�����wy�M�Ux���"��d�c^M����.�{�5����[�z��on5�^���!��E+��'x����7-�-��������@��a={-���p ��y�{������c���X����{���&T�b��m�������������!��]1	�8y��W�E��@����/O���4Y3WDZ.alR��0:����T�q�X+��w�(���i��5p%�"���&��@x��S�4-�^TW������4r��%)���gx��\���
�O�=$�QJ�f��9.go�����@U' ���6����Av!$�K���&z\5����Dt1�����?l��p���=������P�=�[���y��K���{��^�%�7}`�k����F�� 4{,���!i��
�{p|O���t����'���V�Y�b��Fd�PpH?�(�I�?n�����_�������;<$�y�2��v���MX�k�u�5��>��d�{������4R�Z�&�����!1[���T<�[(�Z�2�g��7z�}�u��{:D�M��A6��A(0q�����FC!������h��/q�iL�����f�5{�i?�7������s������mr�6�1��8i6��C�a�;������l��r��/�[���r$h�v�(�o:+�j���������Eud@ i��,%�������4�����QLxX�����u��b�D�����n4�S[�aI�h��i�Ir�UM��z]qEv����^t�m�������	����P���V?��!���K���0�$u0���H��^&tR��$-D�t^�h\��_�j� j)����rt��7����)��T3<6�tS��tA���?G����i�����dJ�q���������1��1��wN�d�=}�wxfy���_G��%�n	/��]��|Ij��Qb����	������2��v�p%�������?>zz�t{�������:���i3H?��6A&_���r����y9�9s���_����-����G�AhPd�q�56$SEA��4�
M�Q���Q����L�[)�4],��:���)��F�X�����\�A#��b�1�U/dCHETyS��A��������9�-HW%�����J@�+���M�c	R��4'�����du��2�#��t�Qw�������Ae�O�O(V�n���#����p U����[�:;k��wCO]P
o~�Rs']}#�X��BN��4A8������g�������4y3x��l_+q�52H���Z�5���	j��I`���C����#�2��K������X�V���_�;��r��<�+����?���n�+[����2�x,E���3S�5'�'b3Q3���5H���#V����J3&�J�=�)ue������^��K��w�mN!�������!@�\��q{N=i5�0:��\��bq�����������V�}�}}$z��#�>�>�	5R����
�?f��� ����3���l��i>�p���~U�Vu��R��[�|��~��`����'���
�����a���D��S�F�����z}��;����S�h���J�����*�/���.��2*05Nba�?�����o��>-���d:+�������I��8:��0?���B\J�5@�a���Q�^#�F0]�|�s|���Nj����������gg�j`
�S�k`�E���Cqztp�
��?~���0O�Pk8u��jpQ�*u�Os����p62��U��_��r4�1tG�[�G{��	���$j������5�$����_��%�;Vn&�����h5�����v��:-n
W�V��j������������`:����yJ�^�
/����)O�Q���T�2f.Pm!�p{����^����<�"�X�Z�W�����o'�X�S���[f��K,��y.i�� T��/_���w��:��;i����b��|�����WX����I��gd�MR���R�|�2yO#�������|Ct��xv|�Ih^��S��<D������j�~<�deRy����N��������/{�y�|��`gN�������7gX��y�Q����nP~#��������Q�/������&#)����W�>B��\5`�Q��K�i��x�j�:�����aV+T���0����c��A�d��������)��jj(+��|��[��o��C�N�����zp+������|������1�pq�
���F^�v?����G�y��k���*G?���1�T��VT�����g2�'pw������s����h��
�?k[e�Y~8�<�C����a��3�cB
�q>u'��UhG���y|�fVY�����^���h:[�!�l��j:���k�3��NN���O_p(9��k^L�K�Q�����R��pQ�A�Q����bsm�e�<=�BT^��O�<3`�{�3���<+%8Q�C�$����������@M'����/�������k�`O_��r��������s���r	s���qy���^���o�Kk��~���F����}��NP58�?=>L�84����jX�P0���H�o{����O]�g|����P���K����X���Q��.-����KW�$~��I��@���(8{������j+DyU��}V�T�[M��aIt2�x� *���q=�M���G?�8z�k����N�S
�h]�a���i[�o�8*������8:����+9���=�Zx=��G�����W�N��������}w��iz�vB�r�Hh����:�
,.�h0��}���[xR
��p����.���E���5Q��j����P]u>�O�p'���^�O����,��7�B}ud�h��������2V�.���
\����A�!+�L�C���7��!�YM���6P����������5�VP��E������@qx?���,�8������,�bT\yuu��]���e�q�����5�k1�C8��C���f\iC�/q�������Y0�����Hk���h�
~�p��������p���0tO�:��t���)b�^K���9;;�z}���7��yD��&>D�.����lkA������^o���xXlm2��|f��P��h�gp��s-���
�2�N��k��@��z##�bdq���H��>�FL�$(m"���x�B�(ie�����|#g����3z�5=wkc����\��v�����7F!�\o��u�!��|&N�j�O�x�W<�]��s2���;l���wI;�u���q������]�����gp]9?�z��*��~�_��B:n8��
�~b�=�H�h�1�.k�Q�8lD��0��[���Akk�o7vvR"�F�'1BX���S�!)�W?�cmW{'��P\
�[�����j����]_���h��GeN����������c�sG�����:�s�@2Y
��=�<>��1����Q��
�����S:�'x���:�(��kh�#,�t�Ya�/����%(�%����m�.�A3g��^_0$���@�RH���{t�=�s@���Yg��<r���a�y���cy�����>?z*�9�lG<�������g������h�S&�3n<��8O�������{���
�EW���^O�=�0���b�1=�2����������qYU��_a�x��2|]B�����?t���������N�`�-x�W�a��{�H�s��.K�@���V�����L�&1���l���bE��~����%�V�����#�@i��9��\��Uc(p-�4B'��~U��S_l�=�|_I��?���B+S���	/���0�iO&x9A�����k&����\]��e���F��[c�#^�l���l���#�}9)�++"���GX�k1/���z�����'��8Q���?�D�^Y	�S%�*��ZZ�����p4��x��H�,�g���^�o|�+�gx%��
�K����wu5�\M��&C�dPg3�u���p�/�5�-���L�M8�sj������tW^���L���'�7�^f<`����p|�u������|�R�l�I5C���Quy^ L�.U���x&��H:\�e/Z�%�2t<��#8a��u	�F��x��uZ5wGSH�Iwu�k'����IC��eQ_��Jk4]J��L��	-����P�f��F�:��laKBG�J���a�}�
(��&T[�0**j��p�D�������#����[{�i.����!����]Q�2(��s�r2� y��#�5:�7��~S��lG/��'W�:'���/V�@�����@ODF�>�b��vxu�7�� �PD�	!��%��~����x6��VC��AJO\%Hk$$u�3���������E��irV��h����������E_��l�Lx����L�i&�C���X�k4"d��c1��;��zF_�uu����P���LRw����a�����S�\��T[�@a��M����>1 ��?$�u�s��M��PZk9D�������f0��C�w�=��u���A���[��<o����2��=i�p[5�>@��bZ'
�'�T��46B^Lv���r����P,PGfJ������R���Z�?tO��;\�zq�)����r��V�^����N��G��=��L��D�r�gT�����5�E����x@
G=����%�j*��E��^�"l��Wd[%�X(�"P(DU(:e�;���o��*�.x���C9����0F���!0�s�4j����Q&��c�����_���^����T�m�R-./�w�V��R`��64Ee��0LD:>�p�x����b5�������)^��fE�/5<���g"�=�@�������0�:W����\�x������B������e��G�ct�aODw�����a M��JfU�B���J&���(���M���`P�h��'�}�	���;3�v�W|�T�be��e����3����4Z��V����?<���6����ED��b��d,�(��D��p����
	tA��1z��C�N/����A;�C|1{��v��7�Pqr)������'v5���E�1����i����g�(���`_�B�/vQ��P��P�d�uz	��# ;�y��5S"n���Ln-�%�)>s7j@	��Jc/Kkdao,�c��7�:����mjZw��*>	-�����B�����^l��UI�$ ����ti-�Y7]�`��^�b�V��N�`�pK�K�S�}��m��4�$l<+�D���h����o�MR�oBjI��D�j��������������w�P�A�Kd��l;q��cwDS6�Z&�kx��s�x���q�<{ m�!���
M���<,;���FN����q�9�3j���]�\h��s4��n������V��HD#S��g��_�b��<o?��}�Z�BA'Cs�-��^�����SH<�Rn�4�������+�v�A]e���"�@a ��Gt�K�
��i�b��Tl�O~DF��"����)M��+���OxPyb�zzz��irC���%	k�q�HM�@�2'��q�L>��,$����9�;����R!���S�4-�*6���rq5|6�L0)=R�~?���}���L�&������a�>=H(�}�����/\�����J�s};p��O��=��	�����@�z�s�.[�k��pw���1�'�!���9�������s�u	3�:�*�q�Iv�!:s���E�cUE(������H�&���F�wN&��b�CDsfh�_�G�my�in_�M���cR��qE8���U�YWf��}����7�wD��[���QO,3{���	�I<�4�sEb�b�'�����������p�2����N�C�Q�<�X� d0��g2��R{�*\�E�����j#X�����c�^��1���?�+�2�I�Q��2H�Ui��
C�(���qT��qJT��6�*�s�5��p:��.�����E��H������u4���x�!M�9��No4��,�\�D)����f
03�>��B�J)-���6��)Z��^������
c�_+����B1a�Q�t~��W�u1i�}���4�TW�G��Jt6�������g��"�xp��($R�������i���C����W���?^xY����"���� �~Bu�'��<G�0�u�nk�H����A�i#��,"`!Km���ZXK]��I�L6=Km9{$��:�mb�P\@�$4^
����A�3��<�������@���c`e5+I�v���,�YxWtvI�K�(�L{	����� ���� �2P
��!CY�*m�%b��2u�}�d�b�D��{�d���{
6�����a����	�%�H�(�����
���f���H�N�h"uc�9D-�\�������A����)�WS/(��<Rf��Z�H�jQ����Y���~� �"��jW@���T-��[�e���L�I���E�n�0��b�)����F>�Q�7`Z5�������~ ;�C��_������R�AJ{/,R��l:;�z���n
Z���:�$��^}���6�W7��[Ate����A�����S��y�\��AD/��� �O�o��\����Q����EC��e��AIx!6P@s��o��j	W������\���+�F4��������l��'���0zF�����|���k�Q�
�	0�J��#��y�P-��[9�������xtA'}
^V�)�J/&8���x��Y�o��oX��d�:�(�'��������7^j�+	>��)?`+�G�����*�������d�Z��/�����k[����z�z]8�\��o�t�t����E��|�wp��B����]z��#��3������!DM������UY�;���O��<����{=����!�l��s��<P�!�������.J�� ��>��:����>����x����v1�`��Z!��c|����[��*|�vQXjm	?���x����d���7i���ll�\7{�����������o��HHA��v{,^���
w�L���*��n�NV�����4��s���":g��@�+��f�%���s�
+���P����Z�|R�������0��� 3�<��P���v���d:M.>��T��]P��t{����z}���{[��$�*�&9
���6������og�C��	�rW^u������6s���6s�50��������O���~r�����������k�z��/����u�w
���Y�+;l:y���h�+��v��y�
.4��fkwc��k���x��gg�g�Va3�7I��]�c8�b��?������
��fC�I�u�A��A����$�+Ze��l:dG�wLC���N�vx7�H3�H+��Fv���"�M��z���,{T���k\�F����P������,�0Bf��12
�=J�=
S�qZ|��\#��*7�X���]�h5�>\���
X3��5�
Y3��5�3h�{������[+���r�\kIC����[|������;zy�ocY��t�0e���w�(���K����%#���e�	���o�.0�y8&��������L��4|'��9��x���.!��N
��(�yD�^���_������s��r=��J�J?���h��k��F�\���=��������������2����`��5X����-0�=���"�[�X�J���������oWa~}����/���
g���=a5��$8���z/�yX���1.
���^&�,`
�F7o1�� ���?��
�p����8�nA�	(�����wu�[����X�n�6���P��kA��k�������?
��8&�U�`%��b�&��^F�5fE[��:s�r����A�#��6"��0�a9�mDI�� ��������S`(��a�'3H�����r�l,��Rfk�]�|���%!_r��|]c()_6k���k�X��Y�u��)����{�[e��(w{��j/s��W�(}���ox���7}u4����Z�)U@P�$nK�����6y�&T��{�mp�v^
qfw�D������\[9-b�U���p��
Z)��]�_�QD�������{�j4$�qx��My�[�7�~8���`���|}w$|��~i�u�;��N���v*���T�A�l�9��\*a����%��8mY����5�N��M�py���|&������b/*��y�|R��8�\�.��^�&U�e��V��F�n����>M���$o��T��������n�������t1�7��V>��A�Q���V��:������q���L�[����#��Pg�wC�L�������9�R����jl6���U>��
��h��:>/W�o���26l���8m�9�P9�
���,5���7L2w������w|4�`�k�m�5MC�{���`�����/�&�`���Q��g�r7�)���Y����I��,7Gyen�
�u���������?���y%�!P*�	sw2��HDVY�Na�A��D�A:��H����kN�]���El+F����q�B��%J��p�50>�-��&Y�S��b*�2�i��wp�Kw�+o�]��;���\�ann.��6��a����hf""�-�/?
�0\�_�5zev������v�,�E>,8�����4���	�j\Qu�5�Us6��Z{�t���H�C\5)� �O�7u��������e�ZM���,bn�1k%����[��s����.�|1~���N"^���/([1��*����o�������+���8|7Ei�Q����?��V@0�����KXBO���c)�*(���V��96���|l��k��6���	*�bH,�"NAdd������F�s���(����E{������m���b�������#���5�.���9�^�����.����>
���{O��u,������On~�Y����{&�������Zl��G#�_��c���p�.O�~x�.������e[��q�m��m(��w�p)�,����*�~6uG\���������){j/"�/�Q����e�"<��M���������B���Br�Z,r�1����/ep����5o_kd�>"�aUVj��h���bC�p��\���f�Tt������~��Dk~"*�-E�j�~R�pK�9�2qr�j2������Z6���������F��a_v�Au���D|�c'm�%x����7
|e��7��J1�����������/0,"�b	E��]��lE�'b���]G�..�Wo���n�~�!��J�K7�C�A,��i�r8SR:�
�W+5V^E��k	�*����)�Tj�k}(�~�'>��F��X������EA��_�7��Bg&aI���&L=P���@A��%��J��Nt�)�~�T�oS���6Re!���� �l����cY�6�"�Fy3
+����<k(�y�;��vx$X�-�3�=���<m���R�����'�
�s���-�7�A[�{ �2[�(?a�n�h�����l��Nh�]:FeB��������D�.�29w=�u���n[���kiYS?��X#�-g����Z���UiN�u�t�?��������c@�����21U@��T��mQ�'���go.����0�C��	�C�����e��\�]�o�D[����c�����@�w���s^_`L���sjAP���o+s�q�}
�����\�S������g�e�:��k�{tq��l-B�����.�lH6�E��k��[\[��E��$�n���A.C�������b���eA��&���@`8L.�����ID�Tt�7=0�%��!�d��KW7�{�?�E��f��hS�bMmj���5�
\/
ad�:�T_o�����s�
G������XN������8�$��Ld��D��it2NY
]�O�S�<d]�1���+_|�7��*���$�s���TF�9	������0��s*W
H��dBI�"EI�X�+B_/X_�����1�� ���f�7|����k(���_G/`���ev��T��LgHq't�4�������{��a��n�fm���1����k)H���Rm�Ax��z+�H�$�?[�x?����M_��3|k~7�uDY��4�������0�A��g���~h�q���J��@S%�Vi��� �V�\�V������J���
��wxE4Y���M!)H��J�|4�Ly�c�z!Mq��o����)����%[�[1�Q;�Zdm�Y�s����q��e��,�@~��[G�I��qP|���&�i~��!+�MZ�������P�{��!d���go&&����n.TU(.
�,������%��x7jp~��y�Yo��F}3\�P�4h���z6�u�mn,��+��B�����.�I�B�Epi�=��pYp������"_sa�g��������\�!,�p��o�-/�7N;�6P��XJ�^�t�����x�����<�J�" ��`�����V/�����X
���z/���L�6���_�~�L�������N^*:��������a���cQTi��u��`����-e��U0�j�*�A]��Qz�u	�@r��m}0����MY4��L�c�L��;������hb���5����U���N�R��9����%K����y��%n���1�������w�ok�%������st���/gj�?Ko��v���d}����4�-Lq>����rz�����,�j������?�-�*�y�Y��9*X��)@�_�k��������$ST�t
��MF!�MN�>��`y�r�t����/�$�l���$|�
�KQ<�.���n�5�9:`0���{�Dl
�'����d�N������6b���}�sw����j,
����
���������y�������:��c}Vb�#����o��`cv.����GH��r�������j�|o�C>��25smh8F������ab)Y��_����d���NP|U3 +4�K8��1�1�O���gBVY8Ll����������)�-�������O.��?8:a�����=��tp��B������fc�
�Q8UYp������G�%����f+��XS���n�X��7���~�_B�;����LZ��s�6��d_{�v�0��'�U��b��j%�9�H�3���f����u��i�7��n��*���!�������)-���X-��"k@�N#�Q''���X0;��r\X)�@�7�u���`R�>?��e�iW�)�3��w(�W�A�:��?&�y��U�n#���7����v;�yn����H�wz���i`���3�Vd�p���Ot�g�Ct��l�:g�dl����j��vS4�����k���(.es�	D�-w���:�l2��0SZ����0J�B#����s���=X_�s���
w���R:�^�#���9U���!������2abc���ft�4^*��f�|L����S�5�&��0�Os9v�.�_���������r�u9����x��{��Y�������;����|���K��|��<X/OQ���F�U�9���lo9���nc��h��kv\w����G^�wI��g������.&N�"s�L�s`5��Yp"�}��0�sl.����������+�O.���0H96~P]Y}�/�5m�:����R���7�����hr�e�k�Fc�y���K�j ��Y���t�O��-7��f�D�S���N�}������3N��;���t��l�z�	Sbw��!0����w��k�����U<����[���H<�:_�H����G��e�����6�s(`��>��}.�.������)"��jt����i�����/5�E�����$:
�'�#b47c�����[5S&PA�
��f�9'P�7��4'5���}�T�L�Kq�Z���\#i�����OE�'_�|dFq��"s(��T��#7l��.���yC.��GU���?����#$�f2U��*�������Q���G�H�B��"���d��w����wC2��8��GNa�8�H���'_��%��t�_�
�Q@R��(��C���_������y��a�/I
Dt�"����I�iP���j��G �A����dLW_�k3��Q��%��L�4�Wq������6c���b�ohKc�l�����H�/=�O���{���?�1�_z���;]���y��P��?2����@��6�Vh�������i.�[/�	Z)�i������2�i�`��Y�M�������Dn���,W�G�9q)l���������@|�����,��O]�����d�h�	Z_h�\P��:�K���7�q��uG��sN�]��+��W������T�sP��A�)-�S��c���=P9�����a{��v#��`�J������%�����):�A�S6:�y�����b^Dk��[<!����ZR�6���.��#3v������hYK`h?������(��q��j�vN��`�lt��!:b#�5��
��^rNx���P�����P�j�T�[����V,ku�~`z�����2�����i0�,36����US;�,��"����I����,��0Q�{�~�nd��������	��P$�p�B%�Mo�<}$��a0�B���� 7Q�I��isO��1P:��4O�(��,�d��a��ye0<?g���������M������+����GH���#�[cS�@�c�=;�|v9�\l66[�����a
���;����^���=��Q��j�XS���x!���V���
�Fv���u�9�g���������=z\�q��DG�������������x�:�_�N��~������@a��9�#`hD�x�_z�0K���%#���X]�g��*,���h3N+T/s4bUY�<�;<+��\]yq����_���3O3�h$��@����u�2�s>CL���7����r���R��>�T���:�_;R�x3��F�1�����2��?!�b��5=�g�"6�D�����'^>mw^��a1�\����N���DU��%�\�`��6���
�J�s��Sf�2t^��=��~�k>|f'����vJ�@Z*LL�ANK�����QIj����j)'����K��#�7�.�f�@�X��T�=LE����j"/���n�6
u#����]��&;�;;���a{g����go�b����se�����@,j�������8y�1i�7�|g����d��z����b�k=�I����I�����TkY\
�"��?��h���#��DVs�W1!�i�!��h~���^"8�����G\������,u��4�y(���k�i�����[-�ir�*���2�]��:�}�0�@�K����;��$
�����x�	=��jG�L������KFv��;n3'��d1�b�*s��43~�7R�p?�	�E�������=*�.�L�Z*�'��;18j������-��^��
�h)
��U=�X�+������)AC�XK��K�o�r���W	��~�-�D��]F�S�V�K������fQf_�	H[Y���i%��Li����������������D5�.{v������J�������r�_������#��%�=��-K��q��l#��wuI���9����.�����K-4����j/��Fs��`������s}w$�7~�m����W/�c6�`�`���?m�u�������#&�����]�\tA����q�>N���O��
��9k�����&�>���!�e��I&�7���!���$�1��+�+�f*��$��
���]OyW��p��x�����)���(��:$�}�Y�����������t:�����X>��QJQ�c���t~K��xb��� ���'V_�����������v�P�q��V����74>�F�q�v���_:57���f��F�.7�u��JZK���Y����t8m��V����{��P����+7pAM���ZI:�w���7x�E���D}�Q��x
C���><�>;=~��_�c��w:��r���
��>��OL&T�J���]0��/0�9������i���N]M�����X\�L���n���;�M���8�M�~���@����z�gO\gA��l����q�h)���`�;���Eu����"t���?�{�m0g[4����N1���������M�Y�_i�J��}�F���t�U4�i�2c���~�=��c�����_�O����!�c�T��Y��r����E��r�wr�>�[��==�����H��wz��[af-�d�q��`}+��#D��q�M���2��_����9W�cs9~���]��ry>�p,��a��OF�&=����������|�?|	O_g?��c�{k}���������r����Kx>����[�����u�C�������\��������|��y��_���NxlF��%�������qp��KY2C�xHD�)�*H�4<�h���_����d��N(CqHW�0���81�����o<W��g1dr	b�����6�����C����bq|��]�����,*~��_��S��	O��;����q���]�w�l�]7p�����P�4Q/�f]4������������P;v�	Z�7���$G[�LO�Bm���'��/�;����.�����N�Y����WD��t� �h�V�w4�v���:y����n��*�a.����/������N�����M��h=���n�;.���$(>�s8�|���U=��A���.�8�:��pd��<r������9q����b�=>B������Qb1�lB���&HD�~9�.wM�6��S��A�W��D� ��M����B�2(���}@/��]{�u>!�\����U������@�	����V�@�l��Gs��E�������3����C�%��m4:���^`$m�k���e
���M�[Y�H�OH��r9� �DG��#�h�����?5��N�����F.�>�����!��d��}Iv|O�5{p���F���^�V��i�h�k2�dQ��U�Q��j#���������W�m,��#������������`�c]���#�]���\k������R����|}G�o��{�l}�����X�^����Vm�FGY��NF��*��w�
��v��so��O������h����Z���WBO<��8!���0)>u�K�}
�8h���\y 4�����=���>
�c�u�`X��������P]�AJx���k���:��& �����$����Ci�PZ���@B������p;�x2�����.2	%��`�JS�����*����=P�jl�(2��N��G�
y���k�K	�<�_��T%q:�g4���r0�J�2�S��o�����������n"onok,���v��#�h��z�D?Y��	������g�4a]��>�x_dg���R�����`�����f�r��9���0$��0J-�B����6������9X�j�A���*����G ����s`?�67S���T2{�|��#�'����8	���������`����z�i��S]�>�J*�$�%���$����#KQ,�	��a�R�����D����\��Ltp�������>`�Y��.��x�I�B��6�\^���W���g�e��WUS*�I�d��|�>n���L���Tgz��s7����B����G��;�����d����g�=����m�����V����&����!�r�u"yG'k#e�n^��C�:�{Gk�lJ�j����������+�ZE�I���"����!��
q����"|;�(����v�5��]��J3��t�c���P�������'6�����$�/{��d#��"���n�D��x�f����z�	�����|��7�#������z�	L�W;��}r��z#����{�a�n�
���1�,����?y$�;��%x,�|���rE?�|	�.r���w�����D�Ef�0�����P~�8S�����)��������,~�r�����3.�!^�.�w�KV�Xb6��X�U�3�a	����C�\�?&\?�N�����j�HY�"bcHFYC:
�B�E2�d"N-�D�,C@�#�(.IP�`�iXn��%J�?�sI��r�q�����(�~��n�t�F6B>P���%J�n��_zuQJ����>mk�{�>;<�W���z����=������9�3K���G�4��x�xEM�2L���yY��p���D����SYk�s��9�X�d��F��uu���g]8B/{�����7�����B�^�������T��w������>AP|&j�|������|m[vpt�>�0�'l���_��^�1�=�������i]4�{7��~@�P�IZ�������l���|_X��T��:��gO���8�w����/�#/_��!�tF&f���G�5�(i��{�X3O���tl�^;���c[��X�^{��=d�h�������G
���x�{��fZm�.��<A���j��,�����������5��H�O&a���y�"���L8|H�d�f��Y�^Sn$=�yQ������Q%/R" `��=������/jZ�v��}���0o��l�����T�M��P�x�H��^W���v�,.r�6o{���uo��x��@��Y��\�H#U #��f��aU���n��Z�(�o}��p��L�0{�n�&O��tnm�#���,G��������mL����w�I�(&�tL�q\7�Z�-V�?����������RQ�E�V�@%5���*7��.�_�%���8��"E��X
fG�E�m���������/�?��2��1'!>6n����:?9��6?����7���`�Xphw@�5���/sn�e��3?����! ����;s����]����=pb�,Nwwq��s�}	�7��9��.K��������L�y1���Wvi�.�0��6�r�s��&�r$����Yn������%v)�����YP��a��HK��\�-�C�&�R:4��K���nYZD��������A��>~9���y�aF��H�|s��K���%X�B��D{�,_��K���u.�,��lt���,�_�����s�1������9�z����#��St������O�3��OAu��?��b 
�"�`!l�T��\K��2��+I��}n����}�
S3Y�Hix�1����m����k9�F�����F����Z�W�yh������ RSt���|����<H&X*�8l�
[���vX�9��t�xBxE����69�X&���I��M�:KK�����j��i�����b`=C���SIB�O��R/�e {_�f��<�.mE���� ��5������(�2�D��l��`c��~i]]��9��������}y���tS}L^��;0���W�?������G�|*b�h��7��u2%zu������b8GJ�Kozq}��g����I�J��z�We��#�H9y���LLkB#k��1�72����0�
�3!��������Zu���Uu�R�lC����PF�m���[*���c��v1���	��X#�z��u�������p&�� �}��K����c��]��	x�A]G�H>���,���;�o��I���d~��m��d&�d���SQ��?������{cy��]�JNc��\w�VI�k!�������)���-GU}�F�J��Zk���V�]��	��0u��TPd��*���a�,�����������_�82���"J�����JC�B�@���?&��9�U�n#���;����v;�yn���W�}�wh����JVa�q�=;��k�6#2���U�);�C|�l�:i�dt����j��M�=O�907������!���(�=��ir�k1����OIX@�C)Uv�B�%0��e�_@�����.�]h0������uvFdGnM���Hk�NB������/8���2p)8E��e�E���4����}�����uq��8]��.�_�������KZ��5uy���Q�����R�s�gXCE�N���a'�����'|~�X������D���Y� �z����#��5i�@�p�K8�->��vQ9YtZ��wa��9)RlB����4�sm.�����L���J-�O.���0H;u~P]Y}���5m;����R���7�����hr��e�k0Lc�i>�k��S5	���_�
��d`&���7�u<L5�S���:���7^���|���l����M�!��@r_��o8�ugp|�on/T������9�������R����O>P�/3Ed�U���(���"���w���F�kY���������q����Ff�����(y�EN��0�����a03����_AS&RA�
��f�9�P�7���4'�5
��}�T�L1�Kq�[���,i���%�OE�'_�|/tF��'�s(��T��#:�;AX�
��\A��0��[`y�S�2�xX�����-�=���G�C�V���z��<��+�	�Bq�BQ/JMAy�{���.~7�Qs�������P0�$������x�u4���P���7����0 ����s�HdW�5i\@-L��2�GPj����AD�*d��+
R�4�6e��6"�p����s��tm6�6��UgY����NS�sH#���o���k,��F66������{��#�����G����A���p~9�����a�����
E�d�##8����msi#k��ny�����f��������2���NQ{Y-��6�W��������j���Id����r�|d����F�/L��:�ik�����~�����e�+,M����������E�����4���a[�n:�����>b�+�}+�lB�Y�jg�����UZ:�X��2�u�.@����z��4x����������K���&c��RtPN��P����9o�b8���>���@F�	�����{v>��r2�9�56[�����a
����V���|���=��A������� po��4���m���&�dv���u�T	�g������
H��t��a0�\�������y ��@�������O���GG?��V�����Y��
^�L��$������y�*����f�_��#��k�J�\��=��~��&�!sU�M���4^O{����kX��-�x�@1<�����tn_���$�F��r5��ge����/r�@'p9)�D��V�-�X���m�����&$�]t$�������7�Uv�wv�����������8���/����C���4D�F�����}R#'/:&u������q0��wYo2�\&s�� �,��[7�.f,���5������{�/�f��(E/#{��@�VF�RT�%d�b6�2���|
��
��C��@5���������6s"�K!8�2��J������������,��Gk�������������=*�0UMV�TJLN��:H?�u������M/`����Ok��������0`�g�����T�55����������Jh��,e�d����x�UB4U����v�Nk\%6�*^4g�B�Ey~�6 �}y������2�!7OC��/3��������f��;��]��

�*�;v��2Z�1�����.����� i0�h�i�����s'?�H���^l����a@v�e�G�A0�C�;h�V
���h�7����;>W@������
�.��_��p��.c������N�==~�wp��������r���0�w`��;�q�j 
Z��@u��L��R/�F������@��dc������{D.n|]h%��H
Tn��n��?C`�z4`Sv=���/F���
�����f���0�-�K�������P�������d�U:�LW�{,_���n[T!Y���'��RH<����y(����;Og�hg�fV�L0OCJ����[������Z�k#,9W�97�/��^N��Du�Q�����.�����i��F��N_>��ui�6����;l�����
8�h��_+�x�xr��~(b $����=��P,����A����s�������
�����s+�:}�>�B��J>���]���/0�9���t���a{a��&@�UVv�H���<^&�yi�R�p�����~$�.Gw)����$�lr=�S(�� �V���wV��Is���N�0�x��AI ����S?�~������`��h�e'g��4���U0������x�2"t'u����LZ���d
v��,�#��z��'y^������e$|�;I����1���������t���}�V��==���*��H��wz��[�zfI���q��`�2�a��W��T?�Q� ���n0P|C�/���K���j������g�qj��?|}����$>L|���&�����%<}��0|����f����Kx>������/�i|�a�X���o�_����������s��O����\����2��u�c�=Q4��?z�@-]�!�{�&!��1������|��M���@����D]�z\d�R�<tB!
6�����)�DK�����k���YF���%��'�{�mr�1h5�#�T��h�O5���+�YT����������w
y!�������]/yW�gf��=���&j��E�Q��,�n������|���[����Ib��y�����v�����q�}v�-�U�l�p���uNy�{B���A'o��v�h�x��B@oq^�(�}P}�������[,�0�u��\����H[���y56�}���i��4�������{T)�;���f���E��Z����.3�phEfx�����^�'T7�>�EgT���R:�������4��X�����?>8������Q�`����]����_q�D$�D����e?s���\����J����R!zK�T(���~��rO�tZ�9�|kkrsE��������h��|:�&kA�f^'�h����o���-'�wA3�u ��v��EG,W�s���]ms5����-��2Gl)N2����H���wu�O�xA���y�l6����4��{;��K��y���!W�����h���%wR3�~~OM����{�[.�������Q���7�������������{�|q�4n@7zM������1X��X_������$8����f���t��gDe���im���8z���-�i
P�5k��F�N���GL�RW�����P�tb�-�uux��;�w6MO�F�`�����0t���������1�4o���o��m��A����J;�|��
��YK{�1y-<�X��D�:�����u%X�������\	O���5u`M	L�@XM�I(-JK�����$������Q���v�`��'��:���=��o'��Z
/�W�@���� 5>Wp��/=�W����/_�lJ�!4��?�J�s�<b)�O&�lV��!]J�p�"G>���g=<rys{[c��\���;=5��N�D}V��,��9K�^�J�4���.�JK�3�7��m�f��\c0���x��r9N���j@���u��?�)�r��|}
�U��A7�!i��t�BC����w���w`Bh lo����)e�y��G�Eo3h�q"���'O�>��^R=��������}T�tB�bK�#F<�v#���X�,����[��E����]��L� ������*�!0����U0�<U���q����?��}�\c,h�*��_�O�M�z�sWu�u��z������^j2]���]��@�Y�$K�'�`6�l=/�w�~8l3���%F�
1��p	���:D�64b�$��d��1����Y�t���co�����O��1����<GMW��h�PXZL��vse��lC\}����.Z?`�@��u�vh����J4�Q4�;}��)p�^e�>�aew^$���^$:�(:r�"�$��7���L�w�|�0���I,����`;���`�`s�� ���?�x���JW����_�C������8}�*��<����qI���
�>O)�����$�+���Z����|�����|����C�]\�L-|#���@�xq���GZ�D�f9]�������C�����%�,,1�$L���
��kFyE ����.�M�����Y;�T*BM!�(D|a�ckD�W(�H�hL��ebe�C��a��D�I�R4���FaAVz���K`F���K����@��!�.���6��:�L/Q�u�����R������i[c����������l�����&�Q�}tL3�Uf����sx���pU qR�qVW��.���ob��ykm4e���n����L����]���8,q�U�,wb*^]t/�Y����7su0�G�A���7�M�9��'^���\����|���OC��e�o���k������i�q��8i�E���:��L�����8�B��tH�r���������M�-4o�g�pV
h���|X[�R/��~;�fw�Y�7/_�~Q}y�Z]���?2��7H��J���c��y��-�o[�����}�Z��5��s���������I��q��>�������Q~r�����m��$�G��������w9�Y4xZ;=-`��dF��l��.t,����S��nh'~���a�6_G���]����G�L��X��{��?�D�{������������:�����c����*��yH�B�V�+�"�F�Hg���-�9E��&��
������@lO�^*��S��
>����qB*���L\������`���B����1�����������i����@�BGO��M�&gY����
4��wq��}Nli�	cg���vLF�<��ns��~��8z�o�<�C)�/g����y�/�H.wS��x6sq��o����j��/��[���7��]�C&?P������(K��R4���T|{{�#3�H��.W�=YPd����Ak�Y��~��i��|{��m����
C�=��m�*��m1�[�����b_�!
���$S�2W�."����������`��P!��p@Y/	n�#��S���(�!���no�68���ml�$����kL5e��7X_[�\g&9��}��)
*����u	��1�~to#������y�|�W�,��
_���S��1�ci��R;��g��(]]� �$\��J��b.ye�+�|����dK���6�Y����81�Z@O������(����o�"�-M��dB�X�:bvE6���
kobM������9+�����e��������`�Z��
A��Z�)��b#/��p�#k'KF6>�l$�P��/�~)���`��'��h��I�L.�L�5.��92:����!IA#B�t�M�A����Gz�Q���g�{y�!�um�:F���;;
R��5��/����n6���*�����F�����p����oy�lu�|2��j�������=q���5_���\��1zK��|�7��������_Q�%����M�%����o�x
�:�8�������j���r�k�������psQ�������.��%�
���H=���
0��^�:{�����o|�ty��R�����9�,H�����t�	u�����^?��|k���Vm�U�76k��>�����0��1��4���l uB6l�E'd��43�Y�lN$���H�hS�hy�����VH�z���aN���j�
��p�!�r`��f����>��{��f���k;���D����QsX��_&y\9��p����]��m���v|��}�~�
�O\���t�M/�:�'�WdB�����nhN|����\�4Zn��f���P�w�������ml�|���6,e���k������xm8u�/��5 ���������:�����%}����m�*��%4��Q�..�����
	�>���7{�������|�\��c6�������r|��r@:��M��&��i��k������7�~@;���_O�rYc=>Q�q\�N�/����x�^�����v�7��j�N4-�h��^��;�J�D�-1�@j�q��k�'f��gR��7��WT��0�rJ+�n��#L;��M$��@��%��z����G��#pk��Hz+01������0�;�x�#Gb��:w�VCc��r$)V��@�c1,
|�.`�!�fl����c���
G��O�����m��U�|�����(�$����.������{Eq(/��������{�O������1\;�������]�+�d I���v�Ye�6��r�-:�� �WW��,:F91������SLN�L��*��C��?:4?��f=Y��Y��#B
Nm@$�#��q������?4%��?�B�,
�#AB���,����z''R�s	McJ��s����p,�}����!g�����:3��d
���]fZ��*���5�#�Sg�������b�Y�+
���Gs�WL�����E�X6s��6ez������?�
����r�!��i�����U�������y������=t�*��.z}��_�����4>}b��b6
.��dvO�$o�����O�E�p�H��c�)��"��0�<#6b)�GN����,��`�����A]�HKYKI����su!�ea�����T�5�BA
j�?�����_cB�[���� ��.#�[���TW��Wyw0��Sw��9�����D��S�4����Q���x>��t���m�[�v����KhsqK�,��6K8�qz,P��T���Y�tO)��6�����+KN6�sRz)d~ #|I�E�3���6(E�)��
�>Z�G`����������&�M�%w�v�/��h���!���i��q'>C��	���f��������:������zv�X��3'�8�T�'i�3���J�W���Z���d�lG������(�,�Jd����}��y&H�����n���hz�?gk�"��NE�e��`�;����E�\3E�jr����|�X
���4��� ���Y��C;�T���%�r�y7���/�F��k��y3��������w�f���}�u���hw���6����XH�����������	�������f������'�p*A��,��<�#Ds���
T�V�&M�f��
��x6��
T�b��nA�G���"��-��� $�/���o9�{KxW������K\����8
�ML���������G���'���H��aZ�=m ���>�[���hS��>�>d.��Bg�E��w*���F�2��fkb%'�"^:K^��^�g����g�h�j��e��+�(hx+�C4k��|��Sb� �������*�36�	5���o���l���.?�Z�v���)���I���5Y)�["��nv�z�?2au��6��������9���J��W�J�#�{Uz���LL7Q�H��(9�M��j��L4���&��^�4��T2����e�*�Rce������*DTV���"o��l[�
�|

�B���U�w�c���^�����)��@�����Z������I�HJ��������n�hn\����t�V�]�a�Y��*��|�y[���QT-<��FQs����kO�#s4W�	Y���;D;����E�����nz��i2���������i�|�����THLy�!�pr�1`�}O=��}
���o��Q��O�X}1�s!����@R����F��<����ms����6�����e�:�
��}�?G,�r�DJ�x��G�[E)������C���7����;Dc}EY.�Y��Z�!��*6��$���+����=���c�7�u�|��m��|RRW���e����C�YD�C��(R�����y�J��4F2{���;O���c��^$T�������P {vp��?�tA�y�W����u�I%�5TTP�������L��z
(�[�r>�)�
�Lo%�'M���D���Jr�V���$})�qd-	�M��!6�"g�OHR�s]v�21)���Gn���9j�>a������;��H���
���}oE���@S*�����-��,��I�T+PR�v��}BdZ���9_�8�1�N�Rh)OR��_26�?�'��W����ii��E����?	����+^R_���n~y�z�]�2>6��L=���$lL�����d���Y�`_���ux��%n\��Vd�$��,F&� ���Z�m?]�'/{Z����I3���=�������8F2x��bS_�b8L�Xl��B)6vSLH�t�z�3����C4`G�0����P�|�s@����p���}=�F\?Kx
���"6�	�G^8�)�~�V�����P|��b���,t@��.z.�/pI�_Z�����-�=tpvK��,-'������.{gx�`S�J2iF�%�S��])�b����k��3��+�eSH��5N���Xl�Q<^�SV�<�o�2�r�/n��;S����.V��w�L4u�/�?�	��j5�X�����X���{\������v#�\��I�L��"�0���(Q�Q\�gZ����pgs�u���C�{BP�n�0d�������mq�����v�Y�n���(����O��}������G�*x�{�rm���LF��>����;p��Gv�.!�&!���Md������>{����{=��R�U�.��B������/����q�[�J�$)����2<���WY;��yavJ�=���(5�Bl�����U���e�/\��a;����\.v��nq:K`�!K!�8G�MEJ��E���q|#I
+���[.�+��q�0�E�����M_�Oq�|G�����h:M�`�-:)*�\|��0b�g�5r�u�6|e?�?��]�1s���xu����7�\�#������.���}o4��;$��?;[~C��w7<�$��"�S���x0y�y����F�{�N�4l!+�M�3���5�Y�4����uX�YdrD �5K��3f;S_���4��3-}O"Y@�3�e���cu+������ED&���F�C�Z	4����{�){f�#�^���G�P'X�>������c��IAiX`�����r������s�l�~7��u���q��'��]s�E;������Y��u���j��|����2]�w�*�~��3�����+��$��f�o��`<�����tX�������0{��4:+MV*���Ju:���P���8P�!a��l5���[�&,�!i��%1@��e�\���X���}2����}3����S	<n�"V+g'	^q�/�i�B=�o���5���Y~pF��j���C
J!���4y`�����d]�7o}aZ]��`!(��@��B  J��r�n1�!�o�����A���ud��M��jAG��b,�9���>�	S!�J�����������u�A��{�����O;����,D�#��G�M������W���J�D����4\~�Z}�CR�V-�}�U��@�����^B���7����e���+��������]G=��1I�����_�.%��>�S���H=����-�Z��{�-@J��E_������{�-�4������V%^^V�::�%*���I5���%�"��WA �N���������d`_X��Z�E~U=�=(���d�����c�`L�������5�c����u��2S�����Q��J��_* ��"r�����2P1/�/���*����Q�x��@AT��H��vTl��gG�����������-*�JW���* l��t
B���@���/���Z8����Udi��=��P`�0�jd�A���� ���U����_�G*_�G*_�G*_��T�j�����[��r������Nj���C��*J���)
���zJ��W=��Q���XQ����P���D�~�S
�)_���F���V��K�I�$M����]�����g�0>�^�����]�b*D�{@���="����V&	so_������+uh�n)����rA*�Sw����Uo��9^��xtM�2A�yS^����9���������+moG�����u�$��yH�&I����L'v�v�7����$��D��TGN���(�x���d:m'�xT�(
�������m���s>w��U���_Y�
G��X��a���������Jyk.�����)��2���8
5�:�M�>y3�L��_��K��B���e�������jS��l��i����<'K%�9�l���J�:��!�ye�j�G�.x������a���`�����h8D����C����oC�`{��,��vVs��3��F|���[���z�����Y�]����;��pw��������v{WE�T7��B����it���j�_�@�Z4S+��u����Kv������}�������!���_������Z����/��u1�6Pm'x������M&qH��@''&�X������ 4�c���?m����������#C�����_�j��^�0���;-V����h���i[�{U	�}��$3��/p
j��������J-P)�Q����t����_�������$�.����u��/�sq���9������A�#��{�eC�� ����v�a��BK�Q�{�>]��E�������7[l�wbp�!G
Y[�����v4K������.6�P�8Ch����$��(���:��1�wZ-s�c�}e���I{@����]��@��V>p���O�^��~S/�����}Q
]��K�z�>��[�����.�;9��C��\
�N�7�/q�9�C��M�������%q���)�����W�z���Mgk��Q=;�������IEK��`y|��"����G���n��,�N��J�^so��t�z��g��;���k�ar�e����������r�q�L��`sy{�v�&�w��n�]X��?^����A�=����e�F�������Mz�
�_��@��h:�n1��b���BE�X$m������~PO�7�|d������>|��6��� ~��
�o4�C���G����8���'��7�JXt{l��%H|K����m`K�7��`w ��$H��%�Hk��3����(f�9	��^$�8����fQ�=(�3�Sb��|lO�6�Vpa<������3��������b6�����I�4~i9Vgg0��ZV���[��J��W�����<���ab'��x�i�Mc����z�����o��}���&�^���?�BW��<�f�p
���(T���4^*�J�f�1���E��$-����C8
����������~��o�d�[�����$�c���8��o��`�1n+'��7��v���}��B�2�����g���w
@��c��A�7��G�{�rLf'p��u�hB:��3���=p~���q�{�t2��uM������-�h�x�3U���y_E�?��&}���`�e�zb"	5�)��!��li��L�^	�Y���u�����D�yZR�d� ��
���3*����V���Y����7
���n��4Q���da������\���=�'%��)K����*9��t��
����;����m�R��"�6xeh���������:�A�@?��a��f��!t������@O��*��@�Y�l��&��P�����cn�]��~��>NeX>C����p���k_X\����$FX��'��&��KJ�[�Zz-+����������	X��exI���_�0���@����M�?��I��Z�3��a������r�;d����}�4.[����]D/C��]+E��J����Qq8l��~��K�`cu�:��@�l��ON���M	�,������1Z!.i#��3NP��o^�m��q��Z<g5r=�������H��+�u!r�!U���Z|�� ��.'=gQiA���8!�.f�\_�S���-��-O����|h�
b�rpp�EN��f��uI�q��A�
`b8@]WP���f`�S1:��m]?,>4;a
�����lJk&���#���{�Z��}�����Q��-*�*K���dx����yJ���"���g����\���&�,�|��$-I����>���9����(�`�\;m�8��i[k#����Q{{��zq�)�(%��Rd*�T����k^.R�2�+P����G�-�|�w���
(/���G6Q��X�9Y��$(
��DH�z1p�K��![(\9����l�J*^� ^E�!x+2����n�!�}��"g ��+c������#)�����*��53�Z(���������{��F2����Q�jR�q��3��J�@\z:��}s9��,����g7�~��F�������qA���W0����=v��cG���vt������*���7���:���	$�f�+
Ra�O$%��-G���_a�����������:&�s�W���@V�����S�n��[��DvzX�*U��Um�(r����X�A�������d�G�e���X��<�S^��1#���3�zY�$m!c��0��%����[��34���������iYhn������Q�����2%S���h�K��O�X��QI�E��AS
�4y�8�C��75�����Dm�P7	�����3��y=�L'^DX��������Y,fW��N����D�Hb�!��a��(�����$#sS�������6��t��c����vLm�-���0�|*x�aV|6R��(�#=4�f�dM�#$K��1�$h��X�r�qa���D��&���o�g�����y�����+��l�X���X��!��!KC����R��rog�������XE���Yy�����7��{�/�av9����&5�g����'{�T��������?�	�� Pe��r������gL���9�g6g�	��a�����Te�����	EKf�h�\H�|��pB��+��U�S9h/6��T����=q<������W��Z�L�+m�S1�*��Z�zd�������
=$�Bo��
y�WX��0�����h�N�e��Z�)]�e���=m�������p<�-0������=������"��������&?�`��l �J&`�kF�"5C� v�k�L��|�E�v���}jj�u'�@"��N&N8��ib�4�V[C��NT��I�e����B���a�`�������b2"��L�O��&��\H���vl*�^�r�z��JSS���S��l��@_O���R�Y���{L�xk��!�'h�6[���7������aU�CJ�uG��h���%�+@_Qe�m[�gjO��O�S%��t�D��a����F�#�\�:}I�m��*��;|���%�������L�V
�X&66��X}�����>��������|��|�t)Dn�p>b��B����������&%��dJ}��~<��������'�e
s���Nw��8+T���km	u���#�%@��*h8�oPe����u��L�Sq+"aZ�s`U��_��P���(b��
c9�JE�������}f$v����*FE����4uc�<g����d����d��A�8�<�����,���"bI@�u��1�5����eS
��_��#{�@���lB�r/�6G�yQD�5��=��]1�� �)�H��Y�qUXP�CA7���_r
��(k
<f)
��2HV���S7�t�WT�X��m<�����X����=p��r���7����JE.����2���GU�| e��J�&����e$�+���JG�K�x1��{����&ZXzn/F.�����F���[�����`��}8����n��]�,�~@�'.��,5��@��U�s����H�;�zK�Z�k�Z�I���j�nt��Q�.��uu��>}?�X��|W�X��|W�P�,��!��t3C%���s����eM�MV�<G�TM�l�������t-�<�P�}���-��B����*������������I�.������%s�k#��;o��:�I#���T�$Y
�0o�F��}:y�����TT'i'�=�e���}�e��}�E��
�.���bk�<����l�Q~C���������[4�'���2�j���R	��$�{���5���\�e
�|��+����Xv���)�p
���*}���r�}kG�e��2uK�.I#���Q�!"��D���zE_������/T�����Q��r��-������������
�I��7��Zs�F�m����HR+��x��=�9�k/v6>J�|`sd�`1��
:0
���"5Q9���N��d4�u"��{�oU����}�k��}�����R��1-\�$����4)I�Q��WI_�dV
�������������73�Js������8�8��H�\���?�������AKn���W�w7C'�u�e[��]q�n6f�n�0�����g����}uqy����Z;}��5:9;sD�C�����=8��������[���2GO�%����Ve3(����ctv�������N�^_b|w������EX	}�1G%�0e!2�zI�C�:a);I�����������/����:�o�2�z&GD�+!�	�N������r��Jg��8s�D�w�Edd=�	���J^�����s��%`dt�H(\�.��XXr�����6H�\�rJf�M�q+�p��]\@�1��Z�#�]0��h�k����L��Z�T`$�W�M?(���A��?G��'��\$m[�G�n=kDJ�{!��B�X��#�n��x$Z�\BDt��
��^��{}����-��D�&�56�T(j
GS��������l�|p�_���%��E���"#-$����=�p���~B[�jP�S���E���m�d������rM�7�8qzJY���p���e�W��^�:���fF�W��W�M�I������V)�w.g���,>�im�F��
��C2r*Q��8�t��l/��0V �A3	;<����?�8�p�KG���`6���h�����G�������W���b������>8����]P�_
B^F�,H�o���i��"M!�c��E�h���qpa��%�'�"���qY���l�!
s��g��x��������Y@�2xa/u���I���Jr�!������V�fF��7����e���*{���YMY�pF��l5���`{���0�d.���"]` �IA�FX���Q-!���m4N�����g
�����U�����������l����j��4��q[�K$aTN��c�1;Qpn�^�����-����H�s��Y�*��Hd`0�:�s��V�
�#����WJO���T/>f��w���c�5��H�chB�����g�.���Go������g�/^]�:;=z������>:??z���
=D�����W��O6�O��	���3#���VL�K����a5z�+�p6�R&�(/�L�j�����s�_e�eL��5��/QG�,��g�AP^9G��iA��J�1Q	G�zE�K��	sJ6 �N��0���+����\�L�
����0�S�M����3����-�����������x~���]\�c�������,EDh]Y(~�'-"iJ7�@S�ix��=���}4[����2���o��#g�>�:SZ-�
���38 ��qi��x<� �P�e��u&w�3,)��H?���w��,8���i�Hd/��2��'�dJP�;�����H��Z�aa�X�UU_�>/wK
*���u�)���X�C;�����#�p�q�f�BH��K���r~t��"�O=��D��*���Z��@��l��e@�4��B�Z'�����a�O�����bcT�.�]����n�Z[�h4������D�=�fm<%�6� >l� 37�N^C��$��G���j�i��uD_�������-��
>����hz>��|��8|��iA��
#n�����Tt��zT�p�&�W���,����*e�t�+T�}x)��c:��/������>������M����{
%'���Ys�h��m!(���:�W������P���y��Y���� b���}���[VIP/����b���u\�%���n�{�������"�P���W}�>�+w���:����g3J��e�iV���2&|�����*6��&Z�r��
�������gS�[`���+j�?<���1�)�]R8���U�`���x\h���,x�!jc����������ef��>�_?��P��t�M����LF�-�Y�5P�����?�
�
q!�.��v��.!��%I������t���4�����z�I�������?�E�������f���N��u�I��|���d����P�Ih}�m�m�L{O&�t�c{�:4���3�-&6L1�����n�T,��/���������~��1�f%�c�
3�7�������=���������w��m�J���S���Y����R��:��z��Y�i7���P���%�$'q]���A� ��4�s"�����0��xP�]&�� "FO���j�3G8!�9�h��Q����8��y:��� ��.(,�[���N������D&tN�X7������w���^E�>�N�"�
����dg�Z����|�
J�I/��1���"`���1CUD{��
���E����j(�f[Q z�oj�{�z�$@�Y����l����{�v������|C����5kg�D
{�\���v����q=�g������:\����+�h���'�T�/�4T$������-f�������$�:��� T//I����'W���L�M�i{Pp�5.:kh8�^R��1�WF�'����-���	��F�?��%����\O������X1�����E�)�v�b	w�����-!~�����=�>��OP�����������<�X_�\2#�X���W$[M�-�&)�����m������������(X���r���$��_����������:#�2�U�^�r����d��a�y�yf�G���1��k��(�.��|������/����,>���{�%Kd9R�\�w��J����PU('�hE2� �a���PK�e�	V�3Ib�d2�W�f@������v��d(%��k T�~��0 ���	�:k�����Q�����/�����R�U����4~z�������+rCA��v����8zULo�D
�k�a?�����jz�������/���(-��36�-8�1������������`��V)ZYp8��J����I�72����v.��4@v!�NE6F��Z�x� %�Rg(��W����MW���^�1���������Y�XA�A�hI2&��!7R<��j�� e`d.��d���DU�lp�Z��)O���Cfk���|�|��^>r���A�D
�&���p60;���[����Jw{�!O{r�����G����;�����<+����Q��R=TA��`�*���d��e����c������Q��)�����p���J��G�2l������-{z�"Vf"���8��,�OeE=+Pq[�������Y�'���l�?��y�9�@2�m������J���Z������
��?5v����
P������c�!�������;4Q�=��9:��6FT)�9��[��.O��yP^�Izk)������G�����eG��J�2a����6����2��,�j�O��S��k��P�j�CM��k���L���M6��L�5'��F�e�#�������Q�B���SYx
�%�`{��h�,��������y�A�F�9fN�%��L�W�O�m��b����N��mY[���ju��KG�-R�|
����L���3�Oe<{P���sie���~��(��|W�(��|W��S_HgC� ���;#�JX�7��XX�����u^���'�gV ���j���J��VrIQ/����S)^�<�)^�H�)�)�Q����@�%IN��1^v/����^�-\�[���&H~����9Jy��C}*��tC�=�e��}�e�J�}�%G=��'r�Y��,$��v��0�M����?G��M]}�c|$����q�
�z�x��rY���={P�2���d���O�k�^}�q,���4X�'��\�G�jMIWmdryz]��Z��t�9�a%��(H�R:S�Gd����<����^���zc�����nu��U�������a+	r�M����t6�����X�~.it�?��@�N������>,V \����p|��� �G��d[�_����m�-���x~|���O����d-������~��}�s�e��b�EOI���{��5������������[��FxFm������T��\A&8��G���J���h�~�L:���xK���,Wzt�����G���X@T�:����f/3���F�l��j�/?����K|�D���R"�qD\E�-���#���37��4ja|L{o:��	�C�q�����	�����8{	���e|��kxv��nl�4dI���V3zL&���Z��w=�=��DGu���������5�S��(��������b��2<�%a�vinjmb�W%�6��qk]���J^%��kN�@�������)������l)��|��m��`N��R$�F�":�,�:��'z�q]���T���2q����[�D�6�U��(���x����-�_�'a��X�Uj�����k����p��\-�����Tqc+�F�gtIV���� &���]7�Q�)���5s������NS��A���?�x��rG�`���k����0W�B�K��^LfOb�K���T����rd�����L�Ii�P������:�m��"x����n)0wp��Q���$�h$	1������k��q}!NmoLm��l9T^MA#U�����F��)���P���Z��?�f��T�_��R�E[>���Q~�3��{�;9K����3jD8������������L�Y�H�����C\=��%)���J��A���+��q6���LE�j��'���'�U<�:������;�#1kh8����vQ�����dZ�z2�
�UBE�T�O��{��q+3&��K S��������)[�8���9�~��\��-<��#�r�2�s�&�K��Y��D��tB5�Av5�k^��
����a�SK��������Ctt|�)�b
.]K�(.V�����������Hg'���qg���}�q<��9uz�G����e<���}8I8�D��p��e�?B�al3W�n[d%v����D�:�_��a8�F�����0������?k.���|����|�����F�a�q��D���X�+��`���E=���l����7k���MlBB���m���;��W��On+�m���/�I����Kz��|r���3�Q.u3�}x����N�x==`b��H��0�C�v�������I����gO��O�x HN���Gx�����o��}1�/L�>�"U��nP	.�ga:�O!�aq=��'������7��&�W��r���������P��< �'g�eX@�����2�r;9b���,�[�=][S�cC>x��;�w����rw� yI[�L��'�59����p�X]M�y��X$���g�J:������v�j"��7� �d�9d	��ugIa��Nn�;2���(������Yp�._��L��S��s�'g	[�
c���c�q�U%]��h�v�"��DX�
��|l"���cK�c|��\%�o:�/f�x,�����;�_v,T=�$�!��pSK�\|;&�0t\����	2{�D���::>��}����>��/��"�����=b��	�D�h�����)|9�:Zg_�4�t������%�
��\����������B0�ZE����Nt���X������%������c�1�Eg��$Y��$��(9m�ce�jR��:��k��'k5����<�f���tv����9���JD����aW�S���2D/����2�UE�jt>
���q5����	��b<�����l�����y����#���������{x�pN��7����
�T����-�tBgN���%�E�z���������W���o����;�L'
B�6��{`{D�Q.��|n>�F�����5'���>�c��j7!�O��)+.9S�V����3�t�:���@�B�$���`\\��
k����R�%�q����)�fBo���5_�@��.��RCc.
Kq/$E,k�cYL������d�tev�����j�/pYC{{�f����N���5l��=�H)����4��q�I,���((�Y;�8
���m���f�l����nl�]Q���"���Q��j�s���-8��Viy��YV��5��%k�A|� �C�
Q��i�XPl����Ak� �nu�q}����mQA`l�D�
6��$��d_�^�5)�����f�7�j=��eE�.��5��(cM����ie�h���Z�����P�8m2e�q)�����6�!�P�|�5����h>�������tr�8�xZ9�/�O
\9���:��
����������]r���/�*jF�����QH��X�J/�����Y��!%A�dD�"S?�5���h��D���A.ln:�wD��������/#���`z������t���p|1���]����>�7���t�V�B��@E���.���?TjZ�Reak~��
d=O%��e����,�gw�E����#��?�Q�
�rF����2�Z:
B4}L�������d�6o�W��y0/nLN���8��m���fs{�?�o�,L	�`�H��w[�m�iu���o:�7��h8����U�;�wWP������`v�����?��p���M���L���g�Z����Z��`��2`��6L���SD�C
��u�	NB���f7h�>�S.hx=�3���GD�������=Ngxd����D����	!���I��HDQ����.Q�,'j�"�h^���y�!c�/�<"�"���`�'�/ �e<��"�oZ��s��������������n���E 
���'����v%��K��4+�\���	J����O��_�B�����%��_�1���9�	�\�����B���\I4��K�^��2� aD7���~v�M,V�NX�}#O�Xm���)��p��WU�H��o�t:7�j4t�v�!������*"�18W-��$����Z����l��t6z1��l6y:�0
�O-#����
JR���Q2���"���w�Nx�:�����K�jz�~�������A,R�:0rn�b�6
X(�@���
"���:���__6����K�x�N�X^:#���taY?�R
�E�K2?/���S���� �W�*�(�	^�2����E�`��6�m&���d7�+L��+�p|�SW;
�d�`�y~�}},h/X��1(;�����o���.������P�=k�mny�L��^�S��
��f�R0E5f;J*_>��0�_%����u��Usg<h#��<fc/����Gl*S���O�CI�Ue��h�b�����YC5I9RS�I]�qZ>��0-�j�FH���Z�b0�Uj����H��|I~��g
;��cZ^�zl��uXj�t�����x��e�96��a�e���(�(�-PH
Xl�fY[��b��G,��D����B`��ErkZ���n|m��V��FD
P4�pr(�[\��"0�Vo}�-}��T�#9�od���nW�4�����qzq,���C���WS���]q���sMf��J'n����1���?�����8��G�]���R`J��X�D+Z����*=�z�Hq&������H����(B���gl���4HKsZ��
c��E���g������dr/���}�oS1��$[���9�3�*����v�q�������q�~�q��#�3]��H�!q��nm�u=���Rk"'�~��ta�H�~��ov���H�mB��J���n�r'��)��8�JVn W���M1�������f���_�m$1Y����L�"�z��
a���`�.M���5
�b�f��L#~��������"KD�vD"�VTC��L�T����iR��=��� ����������y��G�M�����a���e+��D��>�WK�W��~���&�? ���U0�����Rv��??8�:H��=1�M6b��o���1v0#��O���^����������aq�q~w(����c*�h7�R����6�B�buYn�N5d�H��\��b@��@]���v�b�:,��F���k�	cf�'��1[���m�~�+�����%d�VSC���TI��r����V2N��g��Xd�f�@���V��e�.R����kj5�l
V"\S�V��=���LK^`�Tm�k�z.���/M�[H���T\�l=�4��87#�Iq`�ORoaum:�-Sr��\�@�)KF��&V��AQ`��zK����[�dxz#�xNv��S��?�V`N��D��l�fWXF�na�����T|����#8�p&��]���.�C��^�y����H�a��&a����Y6{n9*&����7zO��%?��'z�/�vS����G��CE��cd� wr0��!����n�pr'��2!�����z2"�$_�X���8��e�Ay9��`~�����Wc��	��O"�c�z�����qfyX��l-�������s�G�����m�',f0��8��j��Z�y?�f���D.RM0c��rN��Z:b� ��_eU3��L�o*A`�	I��b�����*����'��=��5������9��N��1�$J�^"�k;��\���
�����p�����v�:�Eq����C�������hww���V4�����`����;�4�T��/�w����G�;���?	����<!&�h�E{{������u��@h8t���?�����8��z{T����G�Gn�*����*V��x���1�67��4�-�����L`<�[����EE�c���`�Na��/��(�.��y���#���s�-g��[N{����Y�U�ZJ�����on6����07�<��TFJ*A{v���
T����������MExA���9�z�����?���zN]oO��y��V����5��.n�pF�	.���5��>���E�����?�r��}2��
����58	�r�WqR�X���������M���W#�&��c�v;��&�7�����U���
��V�z��7�TT/�P�Ldd����x�No6�f���78L`�L';����N���`��z2��w���]���R���Ex�a����#�����[`$���H�2��b:�	
�<��#��l��������9V����t�cK1t?�}���p~}!��y<����w=�3U�[�&h���d�j�r��|��1�h*�J��
��z\\��*���/�����jp�������[Q "OY�����m���&��w8���������lz)��_[�v4��Gg�x��K1�����1.a����#�������l�WV���EP��
0002-JSON_TABLE.patch.gzapplication/gzip; name=0002-JSON_TABLE.patch.gzDownload
���-]0002-JSON_TABLE.patch�<kw�����_��=3�o�;�!XN�`�N&�wG��Q"#�$����[U�z�����$Ht=�]]]�nq�:[�5�N��6[���0V����i5n����fv7�nK3��:�svl��L��Z����z�����k6�>Z��^�����O����}��_���?����N�=<?�1|~�^aZ��>��E���u�v���r�Q���������L���+V�j�/{=�������~zzyyy�Lg����j���|����;�S4UM�o�X��O���W+���w�+��n�����_��a�/���MV�LR�/�<��K7���� EJ-���p�sw� B-�p����X����3=�����L_�����7H�$Pj��rYE��8v.-<���� �y�3���?o��5�s��X�U����6�i���z��zp�m�Q�8"��H��w�$�������3��7k���<�W�������hF�����[Nz�7�)}�}����D�$<���]k��������~�����V���e�`s��xz��JJ����a����J`,���0��Y2�44IB�T�-5!�9���h��H]k��\ mj,-9�?�����W)1/���)�����9��$����kb�����Z��:��ZH,�|~�C�����)�}�gpM��%f�i\Vj6�����S���es�����_WX��h3k��K�+��+h��������tmm6������q��s����n�������:�j�����QgZ��n6�k{/Na����_e��Z�YQ�|��>l�m��/�<O|�#!��@*lk�]��9?e'''��I�p���
���"��9C�g����$��t����E)��|������?lc=
:�^;&���!���#�%1��8���H�Y���>!%>�+}���~���8[,I<sc����\�uR+�Dc�#R������l��5�u�m$u��bG��F�:�j\{�P��/����]����]@�����5X��O������4����p�.���s�a����_~a��.�����f�P
�w���^�}��4_gbb@�i���O�F���[�.������~�v���2�_������`�x�N���Cw���e�������U�:�!u����5cS���
^kw�uF�#�4*,�����*����Z�����i��^��!Mq����'V��'���y�o��oA_J��D��A��	P��Y��F������p�(���/>���,G��k���M8G����=��"�R�4��=g���v������S�OG�#����i7����4��:�0�!�'(A������T�����`^��y���,�%}H�_�Paqv��w� ���$�����f8�-qz�s`�������k�UX��.�	tay���`�����K��`���@��NEk�����1��'�Z��r�YBWm`X�h*��L~����a��HjZ�?qw|�����{-t4�Wa�h���o�_8��<�]ehBo���%[]�X0�sL�����!�2v	%�{^�C�������?G���m���zZE��5�z��0���]8{as��&���0U/�O�]�86r��
���HC�ur�Rw�9(G,-����|cl_(����>�Mfvv������� ��?GW�2K�q����Y�}������<OC�[Ua%gy+P����n6�ju�6������bV`ZT��h����+����L��YP���?C�����e�xvZ����0cc @�4a��&��pb|��P���.��t�(I%�����}H�R��LUAi{��X�}z���[QwP!2�v��]G���[���8����` ��A��7��@$JR:p����*V��/���3�	-%�((wL	
�T���Wl��Y�Y������2.�
����jk�v����6
g&�p�g�Bx��B����RV>-��)
R3�`d�d��KH$XH��y1� %��$�hL��%ga�]����4�m�1����u1��K1������7��r���hP1g�2l��I5���K��	�2)%R����[�[��a�,$��z��psp����Zq�`����A��	�m����!0-d�Ko
A$I*���~8��E`s���$��;�x��Qa������]������F�(h��?����b��&o��s��}�=����<�z��8�����S���Kr�|�%bt���M�*�����"�����DL�t�	��*�Rd��-����h��k�J4x!��F-����`��1���e����j~D��pY�e������k�jo�24m�;d9d�,��F��!"]��,%4,%�_���q�-�,���`;�����p�B#�t.�`����r>������P���/�Q�P/��I
��db��F�5D���#����bWD��X�L	��6*�)��"�_w��\_w|\Dj��#���wm��i����g4�C�����<����z��-�#{�������VX��M�e�-��R���.dE��&0q��-���p���J��2��X�B%C��H��s��������P�Y��[�ut\%����K�Wl&��i1��b�R��g�00+R��l��o+����:1F��\�t1�_��[)6�'�	:��=7�I�I���[��~v�=Du9Pgk��?��s�w���l�����oR,O�(��\��[�J"0U*" E
2��F9.\T�����+/�����r!��_�TS���	<DP�=�e��RNA^8!^�aDa~�B5�C���X^�����b�+_�}����@�`b�i�����SMD�h&b�9Sa��R�n����x^��d(���@�Nh��S(B��{<�Pd�j6Y�Z�^�N���9����voK�qN�A(������&���|����{�Dl;L�K����,�b%b��\�B8�BF��>���Bfd���*\��#��$�1�-�_BY��u!����f���S�J>?�`%���r�8�L��5�mjf�����6��R���+�D)���"R,����
��|eF���V���V�6��dQ���Lbm+���>�M�3�0���
��2�tRV�9�L��w8�G��4R<�R�S��
%��	�#9[�O,mS��*sh��7��%�kj��_�2�K��W��1B	�+�+�3U��)��$;G�D%�T�@ID"9�t0"��()�S#���������M���y���5���8�#5��o\�B��s���������F���huTdz\"@����o
�IIF�su4Z�w��+D��n���CY����l�<]�jn��U�Z��6�mj�j�C�?���Btz-���[���82���;[p�On/������t!`D�E�����^"��1f��������4xeA
��2�c{����������	����^�u��w�����v�b�|=���g��x>.�""
�@_�,�
�k�\?�\��~p��>���],�c�Y�w������t�E��]�c��@�co�
�-�"���5A��1�\���6F�j�:�N��lQ�C�������Z�
�x����.������a�n):��%Kwj�m"�����P�lw�����j� J�S����97��DGq��Z���&�B]k��:=��|��������K2�m�a�/R���i��QE�F8�"�H������H��&��Y2a�=-c:'T�8\��Kp�������OJ���g���=�����"+�.gt����r��RR-�	�_�!�OH��qXfb\A��ht&�����7h�����b����D$��tvb1X���B�a?�����S�O?Fu5��5
�J�0������m�#�>����G�����jn ���+�)8u�a�g�c(����m���**	��sb�{��8����\N���!���p!����^:�����Z�����R�J�rb���0*d��R%������
:��l�@���*h�F�BHTBa} �#��p��-����W!�NG:��2"����|m��}/G�
���_L&#����������wl���5H����yR���{�p
�3���(���d���rPau}!;�au!3�de!=w���
$�	�<[!�x�wDT�������*�)d nGXM��
��)`�?�`����b;U�4zT�m6���"�0�'
	����t�k	'�JT���aYF�#���������I��p���������U-Hwj��@rd�f�hr���6�84�=:���5!� 8��+���
��<s|�`Ot����
����I_��CZ�V-8��H�I��)0"/�&����r/tri��#@��'�����:��]�U�PR�K	A�L�z)�����6�U)8�Q��P�{F�"���d�!�<���j��( a-;!��3��.OH'n^��'���k�t�7P��X�,�}��(QM����g��NS���W�����R�H2Y�s3\I� o�����p��(�}6���U��9/���04r�0��u�f�qL�r�����k@8~zC��r�����8|�i�G2f�:����{�:�V��d�K_��%�c���l����V�nZ�M����@I���I�Q��Z_:����
+�3n\����X������K��7�����(��iA�u)��� �8��m���K�����/)�q���q<�u���h�cx���X���\=z�7��	�����)(h��Q
6��k�)���<y������8.~�e���,B �T��p�,|�=(^�]�i�A!���v�\�'�c�4������u��������,$	$���?�GD���(�{I��<�f����I�'��
.���[���V�i2���}��r��0��z��~�W�?f��B���<57�z�G��^���*L@�*z��
����)�����q}�w,�+t.�E������R�c�'z��B����00�k�,�
���@��S�n�D��#���%�P�z�V	9�>����������"�Xp���r���Z���;�}�#EEM�Y�_��'�����9�"�\M1=g1k�Za��r�h���{e�N����	}6�Fwo�#������o��
��_)��DF�2n>��Zz�?����n�/_�o����b.�'/^��b��vzyB
���g�������v�nh;������9|�S�QvBn�&7x0��S��E������������;u����W�>�/��o$�r�/^a���N����w���9|��a>��~������������O����42���P����-^�X�:�}�����m���T@�p�"�����<������?LY'�PI����w�
��&��|����� |�����yG����9y;a���?���F����h����W:�3���H����6��0���l:
�`.��S�*�.���L'sI:�:
��s��y��
��
��w6�����l8���7����d:�#R��V���r��c����`��,wT���~���|�����y�yr?~1���7�Z����
����9�kfO< �w����pfxlx��)F���������F�����dD���	Z�+r�l�`���e���?���C��&w�B�9]�� ����&��;��'��z.F�Rm��"�1R�Y�Rg���9{9��O�1M����x7��H��=���l�����/mk�X����q�d��63N�k�3�Nr���I�!Ix����o��{��#�����z������Z������Kh���{)���W����	Z��Si�������$���0����"V�VI6P����1��9�����[�\��������)��
�I�����*�&&������������A�7�I����,�n��K &�",��IV�<`W��� ��G6
���1��T�g��^������xcutR�_Z��:
&�m���������6�6�L]�����X���q������A�Ai��op:=�f�a��!��m��*!�YU�����%P���i�Tw0o�����=����V�N��o�(��"��|��$�ll��|���!k;�����
�Yr�?H.�%��4��7�������������T�IH������V��E��K���Vq��i.�%��=(
����`�w�����$h�v����G��C�bj�t����<gU,��V#w!z���"oT��[��U�FR��+MG�M�C��#�����Xo������F���� ��0&.���)
%�:N��q��<xN�������WeH�q�o�bX{�a8������G�DYW7(�RYI�qe\M&�J�M��=�_@A�N!6\��u��HXV��JY���i�[Z��U���M8�=%��4�5��2[('$�#�������J���>s�P�
�P/��)O�!VW2K����hx&����Y�;�`2Yr���o�?
N)U�.�h$C����P��%k��Z����dA�K[���
f�&���R�?}��]�MV1v�z���M��F��A��q�����:���������^����Ruu8�N�W�V
�.?�������Z�Xz��i�(�u��Om�Z����qp�e�G74��H����B[��[ �G���J������6j����
yu�[���r�5��W,�-��b��>�Nfb7�
�|�\r���H�\9F�Ac[V�RW���������x7G�/t�pJV��������)�����7����:��`e�3{t��oQJ����N�O$[�r��RN��I[��J;������m,W�
ji�i)udB���������'g���d��x����������Q��Y�i�4`7^�&�����b�tQ�&'���0�R���,r�}��ehS�����T��9�8g^��4���rV�����o��
n�\*��/�FG��%'��a�z���_kSJ���pF�����o2p�:N����2�:>���zaK?#
lj?�[���18�A�FC�$�����/�Su�,p�8��[?��mkf-�z�	���p�D(E����
��.���+:0v��30l(���C3�B�Bhu�h�X3�(OH�:�G�[O��M72f��w'��l�<=>:9�������Q�y�q2@�g�	����D
awic�=��F%��i�4:t��N�*�
,���������(�{���5��B��|���|�LS���R|f�d�V@L��EjiK
��R�]�V6D�Fr���Qt���`U����D�}�Ms:��q-jO6s�ti�����G�/�Y�{�� r�W�����x����!>���8�;��!U���������cy�z+�#�%���g��1�m�+��X?Nx����?�o?���G��&��n����!�k�X�����tAx�vL_%QR�@+D}W�!�C=���vv��f���Z�^BW,oT�*V��YV"*b�����V	V����{'`��4����U�w��Q@���m���j���V=��M��T����m�����h�{�:��A�����%1��*��.n�"3s�(�������r���v�qg8��'
8���H�A&��al������v�$�~���Ie6�~����o���5��h�����p��X\_�F��3���+�^�O��erGU����c�:}�v
���Q�x�'��H����`�p<���W���9�+G#+���b�����m2���eG�`\p`9�3�'Gd(��9�\hG
J,�A
:�
���	O��RXw�Q���_������a����p����n�N9����)e��y���P�����q�F�^��c�}t~>I�����8J��C������j^���$���qtu���>T����������?Do��rN4����e���L�������
0�ke�������cG�O��>�Jz��~��p�X������2�ko5Y\����wtQ�"��xz&u<���
��f5�v�7��%���L����n�'�*e�>UFz���|�m
w��$��wk��������Q��p����5��I-C���O��H���=��YV(C;���^Dv��4�R����B�������<�Z�)YP>����zh�qm���R��S��s����;�i�Z�59���@f�9=��1�pL��Bt�����1 ~�38f�9�/����z���-I�Z�r �f:��������`�u���w�/����e�c���\���eP�4*�(X�4�:;z3�)�K��{lM������b�a�u�h��n�
K���e�9��\�U>��!A��5��j���R��*:N��&`�<�+�xHW�0���/�t
�(@�GS��u�~������t�=2x����Zm���;K��8Y���)���� �w���A���\��6KI�,��Z�q��hH&�.i^	���KX���D����Y:^�v�2DP$N��K&��_�-�#aW�VUc,���Sw����5�t��p����F�J��z������������W��K+��8Ty��v�8�e	��Mn���zy�6er���TEI�Eb�D�A�T{V�8�&���;�����Hs)�DRYUI��Q��^��[1�����^��f���� L����H��c���j���qN���u�"�@��&�
�p�tJ�8����@I�&p�u@�=C ��wy��qTE���"������Waop�/�O���>��Z�_rW����L�aG��!rZ�7��}��k%U9�s ���Y ��jPgS�kL� P*x��%�����^�����Sp�:���c���d:�����<�v�ZL���	�����}}\��$���&����*v�#	�1���������f���Z]��@�w|����`\�RV��
�B�l	]��B���P~���zf�ZD�����3�.���#9N���].eA�T�c��"<��k'7X������~$1��
2t1�u��6��*_��`[���j/-A����_��_wU",7���M�:�����92=/s~UL��JF�wEf��=���m���l�r��I�{��W���_�h��21�T�x��)-\Pqc��Q�#l�?��������F�)ek��1���i�������xdM,b�������{��X�rM�n�'�]����~T�zr��Z�����i������,0��3fGou������4�Wd��^�yK"�>�Xs������t7���U���uh��{�?|�����0
��Z��ae��Sx��Z�,�l�~�I�7�'�������Zx�M���Lz��������
�Q��s`�d�[t��Vp\g#��+���
G1�����
M\���<gCNa��1yF���:FOZ|���z�`����H?���us
B7s�YND����~�?���<����.PX18�%9�k���u����q������eLP�6*�����RI^]$���b�D�K���(Z5+H�Q����*�s.��I��.<:�-e����Q�@�s�.�n4�B�����kPV���E��X8��T�wl���'{=����c��N(�E����r	��xZ�A���^8���w�14	Ul�g;o����WWm>��>
����uY/��Vp����s�/<�r��$����4�,	>C�"E6-g�{��0-�z��J�oGE��Wa_������D�K|������8�Tb���sr��P �`��
�@`i���s_�,a{���J��=��D:������^���,���V�?2:���+�t�=0�w��.�A[��[�w�
ba���(V����s��X�G�bRO��?��Om�>�@�2_�O(
� �E��1���T�&{BL���.�jW�"�9�T�J��0J���.�uh�H��-O��t�1���8!g�5���#�X��'B�f���v?`s@��4B{�&$xL�=5�S��x"������,���7`�oN��L��\��+���u!t/p,���n�M^�Sg6N3SG2F��z����*�6<���[����.O�>�K�#�0��aV����A@�TW(���{kO�@���������PZ$�W��D7Z_U�]_�jW��mt=q�������T���q�#�d��P$Jq�L����)�<��ipUh
��}�Dd7���
�7��9S�cF��'�R]<!��"T�a�%4���m�q��N�6������*W��M��p��P�dD$�T2"�|V,
+��K\/�
n^�x�/�R���d�a�-��������0%g�C��G��k�r�950����H,�G�.�\�>zUL3��������z�d���,B���(�\��Ga����o���	%?��\9n�6&r\���w�D�����:EW���i��	�#J���G�(�{t�oD��=���br=N��@������1g���dO�.Yo����gl��ZW�F��6)V�y��������Y�f��p���i�%��Y������T!"M�a= ���	��t(��*fC�bsp������_��1�VD[��-��2��1������S�zXy�;��<��@)xx���b+�2�e�tB�y��"�L$k�{��96�T�C?1�7`-��2��$9����3�
}"������������w������l�7�y�SY�TRKR[����/�v�FP����
u@���cS@tp��Y����L�3�dIp1,�r���U,���*������>0�,���~y�����g���G?�!"�h+i��� ��m
K�A]X��u�d��,[ETB.!e,	�k,���=���7��������"j#&��pw���z0L��E,���-�YU���fL���]�R��*���~�G�� 	�����z�iP&}�7�O�^������N���^pF��!�d��kV�{F|�Q�^��w��0�cI��}��as�P�qr�\v�1=L&��AJO+��f������vDE�$R�]������ �����q�Y?(��s����:���X��[|���8�M��xO�j��d�<����,�������������W����
����J�g���������p��q
b4�F{���_@\~��Ln?�/vu�~�Fl���t��1�&����<1@����X�L��\["��<��tg��-tRrC���&fS�����SWus/�C����2D�N�G�H[�����q>:�us6�6%���@���
t��f;u2��3���m��������n��
@o�(�H�Eg��R�Z6b`���N$�����'��2�elR�>[ g)6�R�{�HN���J���y2�K.y��p�g�(�,�^����"yA�aX�"������f�������
{�����Zc� 2b86}��dF���]U�o�N����q��er����B��7����������������U���pn����Z�hW)�h��:����h8�`K����=sQ1��������1��k��&[��2E�����������,z���
��+�#!GG��BQJ�Q;�35�%��.Ov�c�%�� ����`�/N�S��W�p�b
2�X-�V�^������<�p�8�0�[����m[���V�x)y�B!�� ��V��BF����p:�g��99�������O�b_}%�9�8�1m�i����L��_��d���Z�c<M_���TY::ay���4�K�*��2r����>��s�j������"%K��,� �<�m�W�}�M�~�pl����X�
?����OW��� �|6*��v-��e'��c[�p"�P���$~����%��������sh(r����p{(���E���	���D�4h�0��<P>�"�����U��8OK�� �j�xFa8
K'1���t>�3���!	�-��U�hG��qk��@���������2���p�a��f��U�$��"�������6"Vf��Ae��m�A�l�^����XC*\�X��KZ����1
��G�r��}1H�a,��AA�T��x���	Z��:����$[����'9u�	q
-�;I��%��p���R[��`�'�I&Ir�7�����l�����\����`#�H�����d +�a:e�y ��L��@mY�#�@WRF:Bh�U1�wp8Rq��H;o�Gr�J�!K�.�I%A��*�
7�W���^-`�"^-\���>U�n��f
����������~O?����#�lu�OV�����^
N6���\G�3�#�?�?���x���#Y����G������#�sHk|C��1���P�,0js�y4}-2	@{�2
��y�g�e������0��4O��l��Q�Pd��#8�S#�
��7�
�:U�xM�	��D�~�=2���5��i�A)tI`���l3��AR0�$$��u�� �sL��JI���Y��
���%b�%�������"���6N�e��%��iM������/ya�W��D������l���*�]u�������R?�����#����YUa������o(�%F^����k������ >kJ�&Ua��(
���_��r�;����wn������
H7����M���{A��SH�E6��`�[��
��5���w���f�������c���w�~��N�UP�<��+\�8 �C�ZS�YL��Q���\w'}��Jz�wnIQ�yS%��oe������M���<�#��A�;p��%>��������}��Hi���x���#������I���yY�ED�j����������\��d"���m��L������x-�$���5�d
E��i�<��^����j1D���9��Ij�2Y�N8q����������c�Y��}kfiwE�U� ����UX�v	\������Hu�r�%����$��v:I%�����l5j�Vk��8���r����p�K����u����65L`�8!U�ad�.�����##H��nM����
���P/}����\^<.��#/6���
���DY�p��k�p%���;�p�CF��hU�-(|i.�N/�SM�U�
K����	y�����.$)���
��WB�ky�r&�;�Qs\�����p�j��;Y���o�y���U	�=�'���sK��0��qV��j)���vSj���(L��t�)��	�Y�O���������� ���9����q����	,d���Z�3?�G�o(Wp��j3"����X~�������x��dT����8��Ykg.����%�7�`2��pj��I�X�����g��F���jg�e�D�y�����}T��R��j(��`H��DL8�C&-�o`�\�5K��������~G�|u�������b�����AA"��Jg\�����F�m��)!��mb���:�v�p}���a'���ig|�L��G�a�I�;����Z-�<;o��sb�ne��r�9;�t��Om��q=�b����lT^����5"���*�?����f'%�7�
�F��Vh����i�dSHa)t�.����Mi���}��,�/[����o5k��f��hl�/[zK��������W�u�
-t�n;���3]<��0���/r����9tt=����^m�`����:�����?<y���I�sv�z]��#�����}�\$���Qg�����{;<�GkA����y}�a��p��l�����E���
�p�� #���Cg�2s-mJ�\��A�er�_�$�Ipy�}��;q�\�������0Jx�3=H_I�K��~��e{S��N�(Hw���|��@����Z�e��'��5�\z��	}��L��'�����0i7�\��j:i�4 S��-�u����<G�n�����\���{�%?�+@��%�i�?rqj���~$�8� H���tJ.^Q�V�����,�5�\�`rx=�����I��RMj��-<1��R2D��n?E�AD�U��PGe�WSe���|���;�_��l���N�A����W����YnQz������x`����}�lt�������I���?Dtb%��f�����|��a����K��vs�������%A}�������'����d���k��[&k���>�W
S�e%����s@���p��>t�#!�����0G%��?�\W���Qa;�����	6���$�Irt���+K�{�	���?�S���<;_
�y*
��<��&��i�l���R����/��q2��������p���f�%@�A� kTL���Kv������[���k
�3��7�>jN�����2qy
� e�=|�v`
.�D���Zt��1t�Z��:�_��<Z$f����"N����5�<��M`��"�T��'��0���D��o��_~P����,xf�`�^d|X]��2�G9F��o9�v0����8x��t- �����
Z�m�m����H���-�z�r��X�d|bsp��NC�����C��:�Fck7bc{�I�t�=�"��8�cC�o7�����}�t�,�^L�Y?�-X��6��~o��&}���ok�a��OD��F����ksg���@Y��
�2��A��b���G���7v��C���|I�-��<�+�9�I�|'���<S�l��h���F�����%s"�������"���4z��&��ha������X�B��G1���^e8��;�w���'S?�(B��FYV��s��X���Oc�[	;`O��a�7����=�(���n�*��~;u����!U?���:��_s�e�*k�"7B�~q>gAc4/�F1_��^6�/��2�/�F�F�!���4����	���3P�"�V}��!^.*6+�'����mY�ss�[9�S�6�<
�����R6�%���,#D4��LQu�bj��@l��J�Y����`�;I�<Y�$-_"�K�j����/����kz������X=����������qK�M�*"�Rt��[�l���<m�M��ts����\������������:�e��*�8��:1����!�?Q���n�W�m�Y|��������"Z=���C�������&�z���G]�$��.���J����.�U�,����AFMy�\�EJ��t2����S6�HCxI����o��"�B*b��D������7���(��JD�%������T��K�V���	�l��{=�#<��f�y�/��I�$���.W�Q/�LF����X?Y���;���c���>���`��dR�B�s�D�����N6(��Q�SU����� �:�����+7Kx�qTC��Y���7+���Xe�����N ����%�$�����<� /�,jD%��[�^_+9���D���b����B;�$��N��H�Ke%����j��� ��z-���>�%Q'�,�;�DS���e���w��3����������^M�e�1�?3;�IZ�2���r���~�������[����:��&
��D���SR�C}B;j�&�%.S��!zJ�����Bv��QU����>r"�����d�3 KK�[����j��j�0��8��(P$�Fw���Z����z@vQ?�����o"4�"c,���?[�j������=|&�
��1�������"�1\�A���L�\���T���OqZ>�&G��b�	<��79���)8��,�g�bt���N���H�<I����{���&�!����ia�>u�U�"�
SEi�H�TSV��������A�F�'n|�PW2���&%|w�W%[�����w�0���4���=����w#.�
:}�2��<��Y�a����hp�=�Y�|v���C��&����2u��?�%$���v\�	N�h8�P6�_.Gc�=;N����(,On�jZesI�;�b��l��[y	���X$4hd|D����?��/�26M=j��uM{s��&�2H���L���#0�����kR ����&\Q@��v�����b�o�
����DH�|���O�i��,J�����B�����)�z-�'l����G��-t������88K'�����E!uSf��+(�{���~�������������~c�)f���q����
Nr�$U�g����c�Q�9XC|,����<�s/	?�����lOq�w��U��Rd�rL��?�=�S$O�q	V�y`��:J�������6<_�2�^;��6:7�#��?�O�F�3���@,B(��; /�����k<�M�5�5���}����bN�RT���g5SO��won�=���/�J�%���2.tuE���O���y��u.}0]�+���������Q����n`<�/`���z��#�(���8�wR�p��iO��aS����BX@+9�Lk3�����>����������.s�^������P�\C|:�#��A�=`)�M��L�Ca�P������#��&��#d����)<��t7��V��m�!�KK�<trF�`H���b6u��'B�^��#%7>������P�A�$����p�E=�
��}���}�_�q��s�w�H'U�0}DI*4��4������4
��	����j��X��
�yi(��Cxam���]�i����x���PQ��$x4���]�P��[�J/�����\&E����{�E",'Dw����
�Z�S{�%��$��@�a_]_�F�J"-	�A������R�!�@�����e�<V�z8��A��lz���~�^��Z�R�nxSF�X�jb������r�v�D���'B�$�����xp}���X�rsG��:�M�%�5t�������|����^C��-ig�2!_�����n|k��4f�ui��{L����ec���G�o�+�xh=������5�Q�V�D����G/�#��J�VT��l�����@p'	1U�A�1��Mh����W�������fZ!F��z��iD� ��'3^a �C���,�n�A��)@��mfc��f�n�gr����*�z}pJ�-mr�R
nU�)�@�����)�_��";(�1�K�Q
��X�R�����HU�����E/��^'Q�U'�[���������0�_�(K7��������Ns
%7v���\��v+YF�v94����^��E�~!4'+��t�F�&eYz�WY�v���c��GW����]��d�~#��F[M������wU�%d�����;�`����;�~��*��Bw�Z0m��e�:(�T3�B���\�`����|������Q�O�R_��5W���(U�lpg}�	"?7��&��NW;�P��:�����[8�R�����P&�o����x�`�P0�A��;����aW��e����	��;u�5��k���^o	�n{�^oT�`�-�m��48�����������BAj:Pa��Bny���&�hSkZ�A��/{Ot������j(�������u�?��)Zk:&k�|��W����%��0�$Q��b��o�Or^p����k�8M����&��d����P�Fa�$�/x(�|��'�������UYu���_6���u�,�j8���l�HW*+�]2�Q�&]t]U�K8���0��x��m��ZH��1a�f�Rp)��d��0�S�����v�tHn��=q��V��RW���c7w������M�J�L3�.�&����6�aQD�7�����n"Oq�B����	�o���d��z��D���>�X���2�A"�Z[B�'O��1y�)A��o&����G�������������~�rq�t[��t/�C�-
�26f��O���$��P����2�U.�X��/�y$�-�7)�K�F���,3����������J9u\h)�`�����W�G�B]�f8���xA3{3�B�f����3;�� }��
��cKDAsh�(�N�Y��b�`��q~|�2J�7���>d��(�p#��3���P��=��z��R�AJR����wF�2h(��`]�D���4S�!�$�h�JD��E�B>V������~8<e�@e�zy�z��������SU�t48A�0��@���OU���8��V���!�qjGd�������AY�h�+�T����y":��-;d��l�#�9�(����2��
U�UW�X��&WnF*S�PU�D��X����x��v{&|�,d�E12��c|h��|R"wB�:Q���o{��+��z���eU�Qf�	~Z�'���{J���{�f���1Z����Hz������\Z��nP��W�������5z�����p�������W����	c���-9�*m_������V�*	�D��7:�������j�������,9^*���\%c��O`���b;����H
��9,����x�����R�^^���S>���e�F��d7|���������������m�kb�~X]^��|�>Z����j�������;%eu�S�,�X�7k�
<������k�}�s-���A�*.�S�r��/��BQa�a�s����n'-����'�����n�O#LV(�6���sN�v7�ykC����qf����GO���'�a�U;P��{Pv8���x\������^�>�o���_����^����
�]��r�K��p3�����$��=q-�#��3'����`_���"m�gI��9��m-�g�1���EA���w-��Vg��fm��{''��s����������A�C�i���|-K����Z�%�������Gn�A�6�mT,|�6�H�(�[$@�r`{.aY��p�n�|�3�������W���ms{��4	����z3p��,�
y=��2��<��W�!���:�7Z�C*lr�m,�M�mf�uN��S�>�g�^Z�v#N���a�F��7��0���H.x�@��Ma�����Z�*��5�o�Q��6+�d�P���:I��Q���v��1�Ym���R���]G���S�U2�1)(������~:J�=�g��5�,���B��0j;�U��
���7=Rc�]V#�����9�'�������:�M4K&��u:�S"N�G@�`�J�����F�U1�nQOW���A���������XY���B�U�`�{�b��xt}U�?x�����Si/�1�N\%co�da}����W�B�����qB��9{K�)�2"P���x{�|�%r�����j������v3}��-�{$,��oAjg�;����c�!B57�i�����An3G �#7}o;mkI��������u]� ��L�(�Z2�S�L;:��#TEU���R�MQbj�b}��� �4g�4�7�����Aj�V�J�U��)����jEy��;�H�uaDU��9S4�q.o	6���������Ef`3������X�hn���z�Z�����#!f���0X�SP��	�C���' D��v.���A����"�&���x�d_��f���P�	�XB�����O����r�����P��������g�'�G���a��Qtg��
3'�B2Y�7�P��aL�g��O������A<2�{o|�:�*Ea�Lz�,\����m@�Z�l����j��%��4�r
!V��0d~�C��i�%�*���e��.<7��@����<|&w�������S����I�S����b��j
��wz��L%��O��G����/��G�PN �6E^]���0G�FN.lz��T"�-���������
���H*(^�@���9`���Bb�l�*�8Pk5�
�(��c��
��b��WY,�`,{���w����������H5���U�W@(\wH*��]~���)��y�������=+]��=�,�c���5B�z���C���JK[��f��C��!B#��$W$2�@h�I�5�,?����>�akm:��|�z��
�4���q��Aw��:�q�����)Me�����f0��Z{=�m8zG�9��U���(@�m�C�"��3���J��x;(B}������T���}r���������G��:�peM��n4��5�8z"������I%	:�T�0��I������p�iT
��R�sB��\K\��gQ@�\�X�( �h���J�j�5��k'�����aL%���������V���L�{���G�>�(���?�pO����%�ygpK\�H���������|���POg�t�
u� �;���G�C� ?��C%Nl��6������\I@I!�,)�}q�z���H�y���B���{/�\�����n�v>kf�o���*�
&�tp�+�.��������L&�������V���^�S_�����RYt���C������p�J2��aZ��	}���V0"�s�hi�9>l	p��;��[i�����F��F�1P_b^���k!�S�RC�,
9Q����~�������}P@��
%�&jQ�{�A`��]��x���,���2M����{4���0�����=�vD��{G;��D��q��!�J��TN� ;:x�����.���tT1gv\3p��-��
����o�%�J�1�yK��[z��O�T<�-O�v�}T�CWR����
�~��\/����,
����M�F��%��	��������K�o�����
cc}�7�c�&%\:�����{�j�j]�(�\��9��N1L�bkK���]�
C�q�UgD�/�+���d�j�
=Uon ��77���F������Y���e��Cb.)�G��/�p*?�{Ja����C��4Exr�"q���[Z�{|�YbmDy�V�ai���J�}����Wz?�%^��D��~�p���8��`��.�C����������}B[�t�s#�����HhNx�D�������|��m����ra�rJ�n�mV�)���,���?��n�=��1��(��W��J,?K��"���;n�(w�Gf����J4�~F�������
�L/�Y��z�������7���n:���L���k"K�S�����������Y��^��kU<=z�>��a_�,�5G�O�<����?=��f�����������~��?��t�D����U�����������<O������U���x�d����g��?`���R�DZHySYH���$GwC���V!����u�����c�q��������f���j=������D����?�\�wX��\e!��,��i��#({��$���R��q�ve�!�l������kf�XVF����U�W���k�:��� 1^k��5}�5N�;O�N���b�)�kV��t����-KO�x��
�=�h/�^<M�k^��^��^��SO?��G��l%v8�������f��k�������P���(��H�{�p����F�3: �����o���n[4�=���t��^KI.�t��������/'�
R�Md��Q1�z���*�{�mA(��RT���w���)Ol$�k�{��O^B%KF7Z�t�/8L��T��!��W�u� ����$����[z(�f�z�R��[5�}��R
Sd��u:@E�>QF�'���6�������B���8�E2�C�b([����]"���LN�_�y*t������~��%}4N.@��H�)BTlO~�gM��;3_a�;�����z���oo�:�!-����9+�JUs�t�����r��d����#M�'�q����9�Q^�w�Sz,G�i�*�l�n1����;��,[�\�R����VO8�����h���l�t�����y��7�v�,0e=.9���E����R����^
��D�"q@�����'�G��6����T//J�D\O��E�\W/O������+��*A�r����o�����r������88���bF["����9G��l����n5Oa�d�B��Wr���:������)�t���i������h�R]���
H��Q�����k+p����X��A�{]Y�q�m��RU��I����u�g�l(��B#�'	�����\��H�W�n?��zHq�a��g<�
>��W9��,��HU�*0��H�h����f8+��y��wI���YfVEd,��������'�$��������a}��8$��lh�����o��.��x���t(����
��#�R_����J�\�5�UQj��R���WT�&�!�Z��C6��FS������*��$������A��
T���H�����O�W�vx��q�A�p~4E-	��84X{3Q��"�c q��/�U1�B�Zg��P����.��F�$&w�������(��Q�����������X�U)	����V"���A��~�$���/�����v1��������DP����Y�-0��J������$�Pq1>��{�~
������\~B�7�[����]�L2��G!�
�i��rr�2P?j�}����W���}�����������L�[��dq��0��F���������(W��s)r��l`i���,���p
������a��������[�%h�����e�e��E3����)����y�u�y9�����[���B���>�6�0����8�73L3Y"����1��9�E�YS���;n8C���d�:3���t?>��Z�xKw�-����p��������ae���6�����
i��t?>�zmb�������n	�F����R�����+������oi��1��K��?/�����t?>�������_V�����2�:)?�d^;8�=/,����������V���W}���;�����6/�D�w]���2�y���X������-G�eK6@�}	����@�
^Y�W�������?	�V�~�O���OT�
V|��h��X�����T��R:�J+�T��^��)��e
�e�?_��K�W����p1c�`So��C�T���%���YG�O���k%V�Ci�P~�i�7�zo�z�7q����v}���.��S.�����{�xTx�_A<�^-���K��gT��UI���6b���b�:���X,vV���^��7�hj7^6:(����o����%z�$�����nJ�xr#%�������A�)��4�p��teZw�`�
�S ����c���\��X��;.�2����Cr��m"�D��E��svtz��?@�x��?Ig��r����4A���6�3N9��=w����5����>����&���^���C+R���t�����n�6�i=�'���f�v��f���3�J��G SJ+�
�0�2��X��Y���g�f�H��\kq���1�����,����D�}��H�W�r�J}%t�p������sK�.'Z�T�>����e'������q��yU���������u��37T�(���?T�'�+��l�n-��������K�1�����0������I|�v���B(T��"��4)BD��&;��� �r�PDJB�@D&�I@(������LO;��cG!�&�-�m��7~�7�jxU����.��{��kv��:���#W�7���9�����Y����k�]��]�%4���y�����+����$6�2g����]�$�)w(yS���������9������:][U���`�Q�R��`Z�����x�������R�@�s��G�1�����q�Q�����+9�F��}�	�4<P�����n�z��o������Kug�s��_x|��<LTH2u�}�����d	]�+�d\������(���"�ce,@h/��eW��N��L&hG�����su5�)���T4
��P�=v�qG���/i�U3��Kx�d!���P���Q%5\,r��1������+�5�G/�MS��h`�!��C,��q��;������4�C��g�l
�p��N���.��"�j�$L��L�$� h)K/xI�]������'�_��r6��qb�,c����m�&*��a(0������+�d��Yb��]k��t��,�>7(����Y����K�����X���Qx�C�"����D�8m��g_Yn�a��/B�wI��0�Io:�V����zHB�`��a�`�����<���������5\��t����/�����)n=��V����K{
B=��B�?���������o��z�1P���Z��hZ5_Ny':z�B���g��:��j=���h����Q-*.o����1�O]���U�L�i�_V���$���N�+t�L��p�[����1��.��������P����+�>�����M���s���]�(��'e-�'v��.����3�y���z�Z��X�����W�b]�\������r+���^!�D�b��f�W��c��7�� ���W�fe��N���[m�F���h�s/�,q�L��#������^���2{��w)���SU����=`MF��}:��7w4�����pl�3�v���NR�zRP��Z�2���z�����i��8�3Q�s�h50�h�+n���5�G�k9t���	\�J���w��k�P	q��D���z���-����%�b�Sr���g������LK�g�n������/�+����0$�W~�� ����S����/���~�T�
4t��YM]���L��n��S'l���Uj�zcP�e!��*��zh�� ����J�$NL�� ,���.������
�7S|�0���2+]����
2���S�c��F���dN���U@��:����^l�:
�kW����&7����X��z����B�kA�@&|C���'�����v�������"�T���)� ��������i@�����)�/�a�V���U�\�;*kj��
�5��v-!L� }��gTS��8�NY.Q��U
4\����<�)Pu<\8��
��G����QR�xH����)a�F�L=Hi)M�t-7�ac�.��4f�V�`�v#<��xH���M�(b]q��	}����uQj�Q�
\[,eC�VE
�1�G4�gc�S	
�D�����4�*M�J����*���$�/$�NH�
�?#^E���;����b���Y����H�r�6�Z��Vx�*L�����R��F^�HA��P"�A�
���

�W!0@�A?��H�#K���^����_����fU4����_���~V���S�:>�d��7��yc�Gx��=�Z��<�`����~Z57�c���P�/;Sz�S���I�M��~��H�����bi�F�{�e/e/c�z���Lp��.7�v9�5,�� ��|9�J���?:�����?z�a�d�9�\��2L6��	�}+�����gg7�y�7r���4g0Hb2�;��]���z�
%d�����Y����E��D3LsVqw03�7r�����>��3���y[��`Z�3����Q��nNI�����*.�|#w�r�l�I����K$YC�l�_\_&��3N��&���6e��w%�#�"���3M��d�O&e�YZ���jV���9s����k��o�U��������:�,*,��������W��*A�A��}U|����*�|��5�k��}�o����G���_���e��$��\��`x�����'��D a����FJ�������7R��v�B���������
��b���7R��v�7�XzZ�VJ�3N��~;Vz+%=��M�<���OWp����;�#�����o���y��Ko������'��JIw�Y/?������Z�f
�3�#p��[)�j<��[)���[)�N��������v$����Ae��x���/�I�F��*n'N`BZ�b�zx�HN�I?;�V,z��{8)T�������qo����J�����4 ���5����
���Q�0��?����C��h~b?��}t �5)S������&G/�������Fub����K�\���$~:�{�r����R�{�*�9{��(u!��R�8�v���X<�?<m�tkc����%@�Q��S�-]]���l3������3q4f���9h��f���j�X�9Y���o;��~.��/��G�q�������}��:lO~���Rw�)�,wN�^��z[��f����w6�u6[��5��3W{���s�v�N]/�
;�v�$[{ZjSE\�q���}����
�m4&����f�H�o�$��Ggy"z���o���TiI�����K\����SY��
2/����d��#��������3��CMx/������F���)����������`?�����z�$>Y������O�J�QW�Q�o�f��-b�z�w����_��D��1��`���Ef�xr?ZDj����|���������6K_q�",;/��{�EX�9����7�-���=��!�].��a��y�a�U�e��",{���^�el����~���u�e/��#^�_��3~9�1���"r����]D.��D.��o����~/b������Xn�����E��t�x��X�E��LL��O�W+�s�q�������[.��������������"&y���I�u�$��<���e���8�v�I,(�xZ`�/4��/\)*���y:��b���g� ��jB���g�!>{@Eq�x���G��A��w�8��8��?[ �Y�kD���C�g��%~W���E��?n0�b��\�������/��O�X��@@�b��r��%/B��P�/V?���U��w����B��U<m����_2�x��|����W��:�8&�"��%����h�'�����-^��\����(^�^��YE�G/�//���:�@�|gm;�����E�����
^ X>VD	�>������
^�P�����/�1�@����7
��E�"
x��QD/���,^DO+^DO����_08��EK�n����.����Y^Tp����Fz��4>ZU�nge�j�gy�����d5������S�2j�������^��vV+=+�A/�x7"Y^D���G�HVF�Vz�c<��)#l��0%+�V+=��[�HV+=+�A/ylQfe�%��J���� ��WJV+=�*o$������gT��G*��,T�Nk/��w6��zz����/&Vy��%X�l�|
��g��������zc�����3$��a�r�����y�
r�k��	�QS�?~��r�f2#*�������g,y�GBov�;���������[3"�G[J��-�����M;����9��������E^�n�/:��
�l����*:����������3j�JU�d�@���"�C��t��4�Z_�/���z����H���\�;�J�V
@\�&/���
N�7�_�o�@d?��"�_��E��/���s���9�
��`��xZ���:��;��� �y�2��L��_��g;��d2o���-���������y&��p������~�o����+�v���:R��~���W�����������M.���<��k�=��f_�/���\�L�pR���Z����T���qi�E�-��X��<�����9�,@{gN�~����p/�H��7�|�-pQ�g��K���;���zz�=��)����^a���i�6.�r��y��k�9�����a+�ca����X��y)����������8�*���|Z���S������I�z,�{�m���(D�q�S���|����tQ��)|��!}�|�N&hs�5|L|#��m�|K��<f�vU2�Y�#%im������F�}����_s1��s�5���Fv���j�y�j����nw'Y��j�N���������cX�
,k[[`Y��T����Lk��m�,�v�9Llg�����=�����,Ja��G���wv����-�����?'v�����;�wj����3�}����������;���5�h��<�.�v3Oo���~n����
��~��F�������W6������6?�!g�+��������[����������9�-����B�9p.����b
:x��Eg��3�,`�yl:��Q���}��4�V�_�����ubb���[v�+�zj�Y��+0�,�k��,V��n���������f���F�X�/g�Y��+��,��`r(boa�9��c�����,}#��)�sD��a����t�`J��Y�n�"Nl�!�Wb�K���J�E��-�n[����n�����	4����W����l�R���R�Y���~�nB}��^w?Ck�r!���Zky���;���
#18Pavel Stehule
pavel.stehule@gmail.com
In reply to: Nikita Glukhov (#17)
1 attachment(s)
Re: SQL/JSON: JSON_TABLE

Hi

út 16. 7. 2019 v 16:06 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

On 29.06.2019 8:40, Pavel Stehule wrote:

Hi

so 29. 6. 2019 v 7:26 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

Attached 36th version of patches rebased onto jsonpath v36.

I cannot to apply these patches on master. Please, can you check these
patches?

Attached 37th version of patches rebased onto current master.

I got warning

ar crs libpgcommon.a base64.o config_info.o controldata_utils.o d2s.o
exec.o f2s.o file_perm.o ip.o keywords.o kwlookup.o link-canary.o md5.o
pg_lzcompress.o pgfnames.o psprintf.o relpath.o rmtree.o saslprep.o
scram-common.o string.o unicode_norm.o username.o wait_error.>
...skipping...
clauses.c:1076:3: warning: this ‘if’ clause does not guard...
[-Wmisleading-indentation]
1076 | if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
| ^~
clauses.c:1078:4: note: ...this statement, but the latter is misleadingly
indented as if it were guarded by the ‘if’
1078 | return true;
| ^~~~~~
gcc -Wall -Wmissing-protot

Regress tests diff is not empty - see attached file

some strange fragments from code:

    deparseExpr(node->arg, context);
-   if (node->relabelformat != COERCE_IMPLICIT_CAST)
+   if (node->relabelformat != COERCE_IMPLICIT_CAST &&
+       node->relabelformat == COERCE_INTERNAL_CAST)

Now, "format" is type_func_name_keyword, so when you use it, then nobody
can use "format" as column name. It can break lot of application. "format"
is common name. It is relatively unhappy, and it can touch lot of users.

This patch set (JSON functions & JSON_TABLE) has more tha 20K rows. More,
there are more than few features are implemented.

Is possible to better (deeper) isolate these features, please? I have
nothing against any implemented feature, but it is hard to work intensively
(hard test) on this large patch. JSON_TABLE has only 184kB, can we start
with this patch?

SQLJSON_FUNCTIONS has 760kB - it is maybe too much for one feature, one
patch.

Pavel

Show quoted text

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

regression.diffsapplication/octet-stream; name=regression.diffsDownload
diff -U3 /home/pavel/src/postgresql.master/src/test/regress/expected/json_sqljson.out /home/pavel/src/postgresql.master/src/test/regress/results/json_sqljson.out
--- /home/pavel/src/postgresql.master/src/test/regress/expected/json_sqljson.out	2019-07-23 12:06:33.476367183 +0200
+++ /home/pavel/src/postgresql.master/src/test/regress/results/json_sqljson.out	2019-07-23 14:39:13.864734411 +0200
@@ -1032,8 +1032,6 @@
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint3"
 DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
 INSERT INTO test_json_constraints VALUES ('{"a": 7}', 1);
-ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint5"
-DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
 INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
diff -U3 /home/pavel/src/postgresql.master/src/test/regress/expected/jsonb_sqljson.out /home/pavel/src/postgresql.master/src/test/regress/results/jsonb_sqljson.out
--- /home/pavel/src/postgresql.master/src/test/regress/expected/jsonb_sqljson.out	2019-07-23 12:06:33.478367192 +0200
+++ /home/pavel/src/postgresql.master/src/test/regress/results/jsonb_sqljson.out	2019-07-23 14:39:17.629749513 +0200
@@ -909,8 +909,6 @@
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
 DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
 INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
-ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
-DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
 INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
#19Alvaro Herrera
alvherre@2ndquadrant.com
In reply to: Nikita Glukhov (#17)
Re: SQL/JSON: JSON_TABLE

Now this is one giant patchset ... and at least the first patch seems to
have more than one thing within -- even the commit message says so. It
seems clear that this is going to take a long time to digest; maybe if
we can get it in smaller pieces we can try to have a little at a time?
In other words, may I suggest to split it up in pieces that can be
reviewed and committed independently?

v37 no longer applies so it requires a rebase, and also typedefs.list
was wrongly merged.

Please update.

--
�lvaro Herrera https://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#20Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Alvaro Herrera (#19)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 03.09.2019 20:29, Alvaro Herrera wrote:

Now this is one giant patchset ... and at least the first patch seems to
have more than one thing within -- even the commit message says so. It
seems clear that this is going to take a long time to digest; maybe if
we can get it in smaller pieces we can try to have a little at a time?
In other words, may I suggest to split it up in pieces that can be
reviewed and committed independently?

Patch 0001 is simply a squash of all 7 v38 patches from the thread
"SQL/JSON: functions". These patches are preliminary for JSON_TABLE.

Patch 0002 only needs to be review in this thread.

v37 no longer applies so it requires a rebase, and also typedefs.list
was wrongly merged.

typedefs.list was fixed.

Please update.

Attached 38th version of the patches.

--
Nikita Glukhov
Postgres Professional:http://www.postgrespro.com The Russian Postgres Company

Attachments:

0001-SQLJSON-functions-v38.patch.gzapplication/gzip; name=0001-SQLJSON-functions-v38.patch.gzDownload
���]0001-SQLJSON-functions-v38.patch�<yS����O1����K�oB��&��#��W���K��F�,yu�$��u���,�%�R�`�L����3#���9��={��=��
�6��m�]{��w�v��1q�N��rE��8d��ef��9$o�[/��~z{����5�S��r��,��"
[Qz\��N�!�NiQ!F�0G�����i���1��U:�@���������Gb������?]�}C�i�$^���Oq,�����bF	��qa�������X;q]�w^�M|J��F ��9��S�;�krn�M��I�(��_�����90��1��R#��l�6��I{1����_tN�$.ij9�BHw@��`�x���]��������$}R�I��i�����6��O� ���2P���-
�6����Y;�����NR���<$+�Z����6���}�<�Y�@p=J�������ET�X�@���iW`���F���
pZ����������/x�������t� ti�v�����!;�Y������WB#��Ufq��}K��K��r����u��pD*��zRF�YEpDmw-�fg�.���O4j�}��$���p��+��������NcZ�A��2s�������e�����@hT���;�������V��!K�C�Vw(f���tKbG3�����������V<����m7i�%��@�i���'^0+����������WMn�f�o+��#�T�j����c|.����;���f������!�JV�F��:�I�1���qY���5&��z)0|+6��t�MH�;h���:�E�O�S�z����8����R���3�(r���dJL)4/p���*TB:`� ���d�nV �k ��l|E��!!GsV����)/,AW��M�B{���9H�P��D��V��q9�~�BIHs�Z��_%8KCzY|,�F��zfd��Pz$A������8� ��
�H0�@�p�V�����D�/�.��<u9�����D���u��(�����_��c�JM�[���J�dK��sj;��90����q��\8��5����%� ��z`POQ�}F!���)[�G#��rP��X1L�C$0��H�La
6(XdV�@46]���
I��Y�|��H�C}E����C)�1x���"�v�%9a0�?&��)���z�Aol��>���Bd,Q[�|v�7��,w���)^���z[5)��/�"��C�AK��'�2���#������3�_G��|f���<6��r3c�T�K��"��1P
Z�&E��s�>�\x�KH����i��hU�,�,2�|��f��m���K���m�����K�R����A�8P)&��!��q}�y��UO����	�������L������i�:P���S�l�����mw�&�B�Pi���tV�5��9t
A.n�mOE
,�	��|I�Voh4���:J��bV����1�BH���� o��/0�������;`l/p��|C�yyq@p��5"F�{7������q\���iz����zE7�����k�Ib�95D��^�lG�x��F�fa��hK�bHP���N+a��7a�\�������58vL����(L�1���!���a4���_�aOR�R1�{�sE7�J� ��:��0�����q._������&�t*m�d��i��lv(9��N�=byX�V�v�Z[s}CfS<��7���'��	��^
kd�����\G'x�i��>8�%��1�(�����c�����r2��n�=��
�R^�MY����8���h�8��)F��~�.�4	�� �����%)����������&i`����������e/�C��4�>�U������� ����y���w�<-��Y��������-]�����5����T��C�u�T������5>C��������#�V-d��8"�(}��uLR��|U�v�'��`Q����`9~g~�|�!s6���vn�![�
�Cr�{��+2�����#D����N�k�Z}���iE�Z���������������~����n�~������i�C�� /���$74;Mwl��_sh��v@����`�<�o D@>����&��G�l�E��-��������7%�H���7����g��g����.�O����'W� �m��?�@�X7������������0��K��=��=���0� �cL�����c�1�8�����s�$p5�{���"��}��&BJuBY:Q:#�_���6a�F ���2.WB�c/4p�@���9�������$�6������
�_��(V�{��������l<!�~I���}W\��Tt��s��R�i��Qw����\����r�*��MWgg���n���	�k��8�iu��O{
�����~������������f��sR���E��%�#��%a�}D���r�%7�2��}��#�Q;
��G��,�=�=��m���9j�'�����Q��S�h�m�
�r�b�/���g��o��ct�pJ����a�0�=���bE�'������e)���5���+h��'��'��#��@E�w����8Z�-�N���Q���v7��%`����>j2��/����iv��E!����a�M�GX��sE�n�g���H��$�����j�h��G�)�6�����a�i�����ySd�i/&>�ce��4o����u�!%8^��=��H>E��y����<$!>���'5�2,���QOS�	Ecb�F����{L6RL;+W���4-�k5@��z�wc���x�q����JHb�B'�B
W����d0n�Vq���RO�:�e����09�3i�:�����Q�%B�
�V*P.z�+��I���3�p������GF��?��_7��R�K����}v^��.8q�5c��?j��j�!���Y:p61��
Z����m�����->%�h��3��8�>o%��p����F�>]4�d5V�D�O,�PF� p7����CV��N9���X2���bs���K4�������%�����4�jO>�0e����
�j�!�CA��<�� 4��VK���?�d�`dN!���}�0a�;z`��<s��%�^��A��'�#��${��f&Xy�(���8SD�4��^�
��)�`�$�
/b��2����p�8M���E������;�RR*�a���erG��Q���"
��I�8~�����/@rZ�+R���4y���	���	aw���@�D��wa�SxP�!v����n�F5m�O.0�C\;ra���,���d�����/J�:0����!fqDJx�y>����K=���d�Uf�
�����`J=v�U���b�$������ov�&�l4`R�Fv������q�����M�Hn���e�������c/N3>R0�x	�z�A�@��|K�+v�d���������`��l�������a�+!���`Bq{��x����P�:I�V=����U����q��st��zw-�uP���b;� !K���)(���VG��mNf�����N/�O+�l���������m�A�`����d���,�a�O��5,S)��������T~jWxV�RR�\�o� ��^3��i�t������e���e�;s<
U����)K�+���~e����Y��
�x�b�{qLf������]\vs�4w�6����m���?�����]]�+?�:Ci��H���vI�����qVEt��Eq�.��r`���!r���`������L��c����a��^D�tv1;|}��� 8�FF~�V,��tK���P����S��@���f{1lM.�������4����%[d/#}�]�e�
��
*�:�.La��i\��R���L4iz���=H�9
�\�y=��\��xx����Z��c�	�H>�4�&E��aU��[8�N���������(�{�9>�K�9,%h!�_a�z��L:f����r��B���r�MA�n���������|"�	��p�Y�D��#v���Ut*b�Gn�8a��i������������L���\E�9���j�P��R����������<Y�)4d�M6jWU�<	(/�^1 r�%�g<������`����=~������A��U��o���G�J�Q����G��X�%,�j��P9�`��f��w�=��6��iA����2�q��U�VT\�o����Z�`[��X���v|�u�D�V��gU��'K
�3���iu�C~:S"_�p�Y��o���b-fu2�b-3��F4nv���[|����!�y��\�$
��T^��l��-�C3FN��)����Tq�t
�b�P�L��}����7�IP�7�_LS_l
����!g�������9|���-
�wP��p��v�Vn������c��F���e��9�;�_��qP��Gm���������g����N��P����Hb^��)bh�� �F����<Ac���EC���������6�1d���n�,6�*:
q�,!E`�E�C^Ih���F�x�Cq���v�P�:=�'+v��_i�
��&�4���^ ����'��7	C����9�B����BO}=���I�t���B��UQ���5���"zU�EL,�b1������<��*���(�t�B"�y$�<��D"�����i	C��T�}!����R���_%��Y	m%��������a��_%���X����dv:���g,;*:��)��3W���%�5V���?�+)����r�c���#�eF�d��g��P�P�_P�?-B!V�\�E���������B?;*'C��O�E'�kS�^z�+�	��9n��Y�g�	��Nx�K��6R���t�����U���8�1��K����xP�'�y��ci������'��	�A��^�n��p�E���we�Sz�]�������(��|��g�=6�R�\yl_\�����'�C�.��& �+��8����Z�,��E@x�����>^�S��L���M%��BG�W�bv|�d�d7P!�f�\0��(45�N��h'���bGk?� �|k���J�ov��fc�����$�W��4G,bB�{�_�3�9&x%�|7Q�� �;�&�v2u#��m�R�<+��W����e��������"�n0�/�
�J�0r�w�7����F���i�7��a�Z#�?�FV���F��-����7�+�R���zh
w�����������7ok�:�Z��}�W�#�Jc6xGw��3|q�aG|�� <|���:���j0S
�����h���,�g�P����0�����Z�J���@;�E�[����Z}llz��S	0O����c�|G3����UWt�^%4�������q5.~�a�J�	5�v��h���&ng2�@�����qq(�u�7�x��67/N������3"���������kr�������.���������ru���FN��^yN�����O/�N����Kry�������z�����_��v�$�e�������d��?���X�h�-^��S���������o�d�����#�����^��x���Fl����r[�}����Y�����W�s�_.�I�����V����3sA.�I������x!��9��k����mX�<;G'��f|��������M��o������}������/�7,8���f��'�yu����{[��\+��x��WvV�����i�_��������������B�y|��|����������@u%�w���=��^V<���c��l(���P6l���{��Q$�!����&;�_��o��=������M�9R��/�`T������T�-�����A���8�	S�
���A��&K��2e�L��D6n��?{�����,�-����	�t����v��mN�����2��@����������3���s~�O"`����������*]��B��WBE����r������m�u�U}!I-_�*��{����Q�_�:Z�8��<����o:����?�_����|���Q��6��M���u|;�����]�D�[-mnxan�:�%t�W��jN���A{0��:QNb;�ky����g&�^�E3�>���4�Y_G��%ZQz��^)X��U�����U����?�)e��A��t>h�4�N��921V���K�-2mNK�j	����D+h���H_�'�1{��1�L7d����u�xM�������9��������6^�����7������I�E�_�V�#��Q�LH����0���+����#r��=�@�	��u��BG)F0���@�1�?�3sK!��5G��B�L=e��s���W(����U�?���CA��Z
�B��Wk��8����[+�W�������:
�,��8��
4`�~��lZ���Q01
�`t3F�g4���6Vsc�����C�X��Z��D���^��x��qd%����S�L���h�%R�!c!��o��H���&
ao/�v���NM�T�!'E��q�x���=���/>��G�!h��&q,��I�#���i�K�jy�9����78���	~k-���2����%�X�k����Z�k�Kz-���R��ZpI{������/?>w��}�����,������g��Io���x�O�nx<F���t�q���[�SY~[;���w�!g�����~��u��H�n�o��Yt������-�[xy�/,Klt��*.�������m��\�x)����j��TH���Q<a�m�%��3���M����������6�)�C��H����	��T����[$��(���(���4��U��y�[�r��3?�[{	���1&$-F��v��/�\���E�k���� �!��]�8�zY�.VA>}0��
�<���~��\��
�J����|~����������0�*��G�/c���-`���ea%�J��'�C��UY������
H�������.���v���*�TDX'�xU��kJ��$+�{�$��(.�k�p���������c��yQr�*�y�U m��T���
�,M~��#%�A�����$��(��95�R�����EW����u0���O��2���^����D��@�V����Z����5�Ch��BxZ���S'�C������r�d����X������nE��h��v���x���oP�7�:�]�3��}��)�������9��M2�5I�����5��-]�\MZ����ae�����3&����~dh�FY,��������7�DA|<�����d���g@���-��e=xZ�K�N����[������pL�����|�8�w���=!U�����������io<�Mz�c���ux�[��4�t�O(��>����oFVy�1�F�k�2������jJ�s}V��������s6�8oY���\�6������lrkRD�S�����
)�T���� `��'�#����q�����*������]Jd���r�?�	����xF����7m������e��6��t�O8�d����2�9����v��W�*2�0]������:T�'�!����k�0�lM�f�L��U8qQ�VW�~�hb�+��J�2t!�u��;����*]�O��@|�<AF�����[>9�
��1����sNdFW�����E)Z�����!��������o{*B������l_�Q8�!�NI���|��*���{��eg{}�R����O5�VT]�������z�T�;�-���w��:n�g�6&kvL���S�����o��R�-����b��a��r,;�} ;����/aRc��]�Z|�p&u��M�m�n�Cox�d�N-���U��d���Iy�������d����;l�����h��I�\����[���|��=Q�t�q�XId��g��_~�(2��e���\�cf������"�T[ZtS������p���j�z��9?����B���������q�4��vLn+������[Fi���_�n��K����_����Q��^����i������]�nH���j����l�%���!�R�ih6���pR��1��p����p�d����vuu�i5��C��PXm3�q)�M~ R8��Z��f����"B
�i���z��ZD�.�C����;DN2e�u5Z�,om���7�S��m&Z��>�h���Of�����8Y{1Mf���;7����g<�������rR���A�@���"�Gm�F����t����@���b'����
�/�B!���2���}Y,�i�`O\lZr�En�R����!>��WP����P�<x���I�����k?�]��'�����.joYE-�}�<w�;M��u<#L���s;V�W#�|�x��EC��r��f�@��_~]��{j��^��~����(^�"���sf��o�Nw00���g����j�����c�^E�g)����pz��)�(CN��E�T�K|��*�'~��!xE�\����r��v� ���O���@	>e�����R�x���6�U�[�W;/r�WH���=G�������S<��N�k�����X&6��n[�g�1c�L/��x����0��~��/���y����h�T������>��a^O���JU�uv
�Fu��'�uL���+�FP}���x�`U2g)LT�M�� �.�L���)����W)�C�a(��j��iS7������3���A��vQx��#2���&G�F�=hO
��a"�����+j KG�&G	��"6��d:��O,�(L09�}��7CnuO?���
 ��YH$w��e0*�B��Q7�EC�l�Y�4H����A�L:��RV\z���&�qV[z�RV�7�t�����'�i�_�t�._������C�^�
�[@��`^����s+<�9%b��2��SH<�{8��&wNY;�
7���nu���]���Fp	XP�4};2�5>��>�Ncp�oQ'�S*!p�V`�
H�����D�6���"������-?����Q�I�F5���Y�%&�ir���
�9�����N=V~	����^���l6�o����4�l���jv]@��Tba4��c��p��>���s��0�����Q�4��DN�}8�QB�WWe�����^�Fe���F�,d��A3��R��2@0�&�J�3�����-��k��0	.���S�u��l`�������U3
����,[�h� 3b�27�o�������w���8bi��V��^"�I�4����a�"RLIh2�F��7�M�m�O�n�&G�OKL����hI�,8�����](n�h�gJl4Se�Q�3KK������2�0�X2�~����Q-un/
���G���a{rW�!EX)�A���YO��6��P����1�J��"���h���E���
��H<h\L���(������c=R����R���
����4:��r`�%��=��e��6�F�W{V��{�����P��l����G�8�B/\d�zt��L�k^������{���� ����WMIu5����3��[��v�n6�i_��{�������O@^Ib�������;�5� ����6��e�U=� �G'9@`W2A4�����L0�f��<$�����c�1#�Q�$T �$���4:�'/����Ae��j<�IX8-�&��3�	o��#�����Y�]�m���'��Jz���,���1�]�1
��L��#ckP��g����46=uN��<��	K*X_b-$�2B�
QW��V���������Jz�����9=u\~L�o"��a=b���@Y�~���2������J_�>��\���[��j����s�KN0p{�nG{�3�DoF�����.i<N����3������}�D~�tt;��ghj�:ds45���jS�4R�&yi�e|�*?{�U2��I9RP����S{H	��@��,��\8��L��'x�;�����]�9*���>��n5/��I�k�c��Tb�����$�2�0�Z�M���Ft���%�XK�#i^����@:���XP�aK�B�AB��4��R&��T����:�8�CL��b�5��.f�Stx���I�Hr��`#Q��w�M5�W���5=%��`������ATkd��
�
{*^�2���h,m�_����A<�m��
���&�1]�����#a��xjGo]�`cOQ�]?=��o��&�Qt�OGt�)3H+V������>����^�����J�=��}��5��������'Z8�}w�(i+Q�o������{�T�N�T
�S��&ZVD������q�����1�
(l.d�06����P<3M�H��0��?}������Pz�U��0��7������������;�����IE���$%�u�k���'�����������a>K{��U���c[��X��9h���q{#Lu���{����7U��������Q����K���������<303������>�]
�Q�e��D}$��S|B^��G I�o�R��p(��7�-�L��ek��1��1�����f�����#5�k���/G�t��;�_Z������B;���J�G�p���Y�E;]+���F;��J�@���c02�[sb�7Z��a�#��c��T��=����)6��%}Y&�(Z�<Wx��������~�N1�K����en�>��
��V�n��Z�Z���������8�[�x����Y:�m�RB��5����X�����SVp3�QJm�����6���{R�K���\��Ktz�������E���ul��MGJI�j|L�C�%�F���P@�u]H��l�����!�?��s�g�������4jw0CH;�"Y [�Q��lWT"2�3��f������&H
���Dq�Y�x]�oo��vu���$9#��el�*�T/��^H��.�����]��f�����Ua��������,���Y.*���Dm�~�^h�H[^�}��q�ys�NrJ���)Y��������S����l8��U��[�������!��I��WD�i�f�������g3;�����Y�Y�g��yZ=�i�R�}�R����-�.�Vd.B,%U
�C����8=s�^z=I9KB�gc��9`��+�KeY�����v�3/�o�����
��k�Pg0����zaG<�i���Q�c��-GmZt����C_R�������kI����h^���zu�!#>���T�m�1�u���KQ	h�<_��8�Q���'��8�M=��>���Ha���|m���H�� k;`X��
'yBU�MN��1�����f�q/^&@{���!Z�����:��c�C��U�GTw��8��u7s�-�eYHI":
�	HUY�[I�$�,���I�f�6#YXW ����W�Y��b�0�H��v�e,���:Zc��Q�hi�B�"���`�����4xb���Y}��'��X=1YU't��QP������_��'�<2��|��{�^��;2S����Qt�x��9�I[yl�0�����aq�7:~����G�"��������
�:��. N:fs~z��}�u����gL�d����m�k�R��'`J��Z�6����U�}�k��&7T�Y9�E�n�T*�����6Sh��V�jy&)3<&WS��[��c��k�}RK���\�*/����dW2��da=:o}���8���
��M�`�7���H�X'�g��)���;�o9O��ze<5�g�������o�����n���������Rr���Q�V���������n�~�=
N�>{ZI
@�Y-S:����X�����T4!�������'���@4��`����F�_����M'�@"���H
x����9��5"9�.�S�l����rn�����[�zG���M�������f�)���zw4����>
$�����V:����^�����L��$���'�����-�q��D�-,R�l��J+��h�8�g�o����Q������z}&���p2�����}6�_�8h���~�{;����������L7�.R�vu�9�)�bo�q�W�p��l�����ad��cXK0�r����A� �#�H�"C��bdl1+��-8j�2*��,D �uG�A?�>�R�_��`����@�<�J�����R���	�J�\���4F����r���,��
v|��S��8�k:��{!�y�qN��y�$�����hEzbv��<��U�S������x����?�w�`r���3Z���)����H�*�2���]����C�A�W��l�U���yl
�.�
�~�2\S$cf��!�.�Ew���M}�K����e�*��V���$R�����PS�C�y��LU�F�3`c��U��oq�(�#��L�W���������R������C
.9�V	�
,x�X#T2�D�M�
���X�c}�_�{��[�2<�����}��z�O%�S�n��\���%0ul�w����&e����u�6cz28�G�*�P�B��;aV�_9��O��Z%�![oR��K�9\�!5u9����$��Um������U�����bSC~k4��'�I��'���2�u���b)�G��'v������d��=y>(���(���Q�#>��L�@������#9�o�A�S��Q�3�p<��?��J��*�:��J��3[1R�wiZ'L��u�����]}l�[)j-�[���o�"M��(l�3��?�^�?Jy����p5�=���6���;���@�m
�R)�ty���/;_����;�%|�s�����7�/f�������oSj�+����\J+��b�/�f������9�/�y�*�(���)RG�l4���L�?�gM�'q��W%���t��yn/@�����wi����M[�e��`�z�M������+��@O�����Lu�W.��Irh}�(sm1&��m�5�0�<���^Iw���s=�c��yFh�����������$�}|�u�?��j�z��JW���������v�#�C��n1hm���o��?t�X�\�t%/������Q�!J"J!)m����h��a.V6�����r�:BL���:_�������m��)c$�eH�wt3��&�����d�����0.N�2���_��k.,�X#�V�@)�D$m�H)��i��<@�|���Y�V�����J���H@I����y@�R-
����������$�ti��<@�F��w�Ed�0��c��i�y�, �����xxc�Dm�i`�40��s���l��������a}.�G���w��I�����'/����F�+5�y�����Y�5v��)�v;���������^g��"���)����7�+nT"�`�.E��{T���.�Y7���M���w.�3���.����]	O��|S���x�t���������	���r��_N�}6�B�9�C����m��Ju���2������	�I��$	�x��4�:�$}w�����&bk��Q*oX�����q�������Gy�-�
�b_�GG7�=��X@�u�	a8�q�^�s5"9�c`���O����gz^8�7����v��S<����Xd�c{Y�+h-BL8d�
��s���;ZhF��yK�_RG����Qj=����j���_x���������,-d=KB	��=K<�?�>(0�����t�O/s�"D��l�)@���,�iv�Da����~�[	����=/[$�Q�!�����{o�scJ)mq�O1:f"#�������x�2���������1��5%&^�|��
��w�*|k����H1.Z�=%Eh��������X�P|�����w�5�Z���*���f��{�y��[��Q�~2m��@��K����
��49��T�4n�@��1E���Qs���IY�I�_��1�;����V�lno����{���F�r������}���-�=���GY'��K]8i"���2	�
u�qF�ppwc�
��7J��#�����������.��+x6�h�����ra�	���W�ApLqy�;���@���3�// ��>9�H�@ �	�;�)�m*����j�dA�k���%QK.������0�f
�d��`_=c�:���d���e��j;kx���7t����r���)�q�wG�
�{u��9�^/U����}����:�Q5RpT���h4�O���1��k�)3l��]�B�y�C/p*�!��A�P�X� / ��d6������r�;��F�~z�z�|��?�jy;�ny{n�j%�r��H
�:JD:::��v|t�!�vRo�/8��<���� Q��E�N�K��b��(�Gr�:eN�=�0����3�����H~gwE�|Y*x)k�u�����q3�!#���/�Ml�}�d�(pEK�V��)h�}v���Kd ������W2<�x��(-���u!i�E����	.9�HB�0����3�������9"��A�"��^����;qgg��=Od�!��vR�o����-��U����l�"������
z��g�g^�����r+���b|-��������U���s�\i��P�iX�J$����|�P����
��K�G�0��3�W�gEz�l_�)^�.�:��@������xI4�I��m?��S^G/��r�\���f�S�^4�����C�5\�����?�����=�m��n^��,����GT7���S���\��S�&��4�{;8�{��:_S���,�P�#o�|E����/g��efQ�/KL��)�X[����Sne������2$��?�N�tH:Zof�P��)��y���|��,/���W.�9`Fy�Z������-��Q�h1�M�	^M�v-=gq?�}���C��_���"�T`a�\�����B������f�����Z5	���J	�|��I�ZK�+(���r�Le���F�T�U�X��H{2�c)R�P|;��`����@1�\�%�����^~��)9�%�.,lj������iuF�k������j_�nF�=��a�yt��P=U�rB�9h�����7AAG1c{xA7�����?{2���Bo��������u�����P�]�6I�T�����"#�:��M����=xOd�����H�Q����&�
�B!1��N�,|+�Q.�gG:u�x�V&]����6�\V8�dm?��}`xl�~@\ky@L����[�qFa��OfQ�s�{�����p;4��o,A���@���N�5���C��� %�-I{6Q=E���t*�R�.��D����������z������e�g�Y}2?�/���7/���-���IH�����U7���p��[����v����
-�q�!�������;�7��`
s�_�:�5��TA^���Tr%&%��i��uURqm��h����:�9���[p�p���w�`�&��C�.S���5�������"�i����Do�I�)��x�D�eb������a0���B6��RAv@xpa���]9�����:(���B����~|�%�~~�LKIg�4�(I���-2#%d�|,I()�a�BI�(%
y�Q��J�����YI�G�ha($"-&��<(G,
	Ka0���W�v6�^Ku��[*W�(?�=0�N��OX_dlR��Oc���OL^!������+���U�
���DVP�S�A���-i������y���x��<=
�� ~_v��m[C�c��c���8cX�.l���EG�5qb��x����fQ|�����f�}�a�fX����|Q��w��;]�4k���Ju����LU�a�S�7�x���IU�<�M�	C���vn����lb�_<1�/����LL��&���O�r�]�7�-X������3�����h(~Cb�s�r����	�&��	�S:D;t�s���?�����O20�����]�)�J�U���e��~��`�|�u&��.�u��oJ��]X���z�~�P���P���w�Z{ff��%��7�
(TEB?~����2/-
�}�R������K@Q�M
�Z�.;�no���������\�K@���U�I��H�|AJH�������N�~�3`����f�u�}0B�|st�L�����oN��%l��cd��)?^��W&�����E2�|��!�2;����e�+6FGvXO*�������q "F�����@�t1-���E���6
Zt�0RKrQrvt����c_$'ZE�H���z11���1����'��=�/�EA~�M�����"4��L5�n�r�Tl�9��4�S�Eru�����e���n&[�H�kbqHN��Dn{�7����
��E���bU�������G�fLG���dv�gg����kD�����z�>/Z�o��K-t�����_�`VV����dx����C���7I��Gcc4;�Y�g"�8�Q&�1&���J��n����D���2&����k��8'�D����
7W�`&�"
�cR$��)��G����BS$X��b���������n���x�Y��z�w����>,!�'|"s�x���^-O�o"�3jxt�F�H�-�xc��2a%/����=����7
"���H�V�	$�1G^���YJ���7O�Ly�|�.;fm�:��D�x�:C�#k��}.��"�fu�,�~�t�2�:�1��+�����K81���`����KY�����m�YM��F�XJH����l,��^>���-2.��c)��s�+�1�fz)�8�������`�,���^�3;��q��Y_�nu*���<��
!M=c���������X@�3H�H���a����e�_��|�K�X���Jf�^�DvI*r�zA��[����,4XZa�J���)�?�t��?��z�^#�c���F�-��S�(�[_���2�E����D��t(�~��I3�{�reG��S�"P�X\X�a����&*X�u���p(>�\�����MJ��3M����~��ej�9�����PegkM/��on�Q�}��M��GE���|�b�C�W�<�9f,L�	��G�>-gkF|rw#	f���$��"�1+'�[W%�|����1
�����������������/��A2C����d�����������n���/K%* ��� �9�p��`�,<�R����Z���$I�1:���"�����$����2����)��(�y��>Y�R*�f,���_������n��6������4T�m��HHI��ri���
�5 Z�/��
�E�������a��T�p���<���|^�h!k�������oN�KQy�8��5!���]c!����\����
N[�Z%�JS���@md�J�UD�n6�9CT��CT\:}�� �����4���H��L���EZ�c�g�?��]�V��\^__�fg��12�T���7����S���vG��~&�0��D���������w������tuL:��Z&�,�*7*��N�J���m�[x{����~	q[�k?���Q`����o���V�+	�P���/���7��hJ���pt��s�5��)�jN��>���{����h��J���}Q{0�f����G(m}�����Y�A����f��:F���xG������5�'x����rz}��o�qR��VLH������T���������<$��� �(�zb�����?��[@�S�%��N����u��y�^{�������v��?����7�5>we�ij�^tZ�����^h����
�S��h����" R�B}�O#o�v8m_���vf�6�dE�6�`�`~z�|_S3� ����n���b���&��#�?pl��8�M������9���������W���X���aW�]������7����:+�}�Gt$�"��$
�����1F�OyaZ�����&���i-1�onQ�����hp����[S��[���#�Ue��D�Q?���P�k����b��+��3�]HG����E�'JR�0�E�;�h���������fs���V���H6
d������O���g~qT/C9���g)��v�Yz�4|��y��nu����>yz5i���y���N�����N�}������mmd�.n��f��'�(��+Wh���8�CB�����!��l��G���������~{�w��.]� �b�<R�q��h�p2+��R�������AV#n��4v�7N�Qo!��Zf�v�d}�v���$��m���S���_a��P�'-h�`��A��>����T�.�@�u�V&����:�����|	����,��UP���S����}f�l�X�����)}�x�F����"�_@nf�6��v�sV`v
���)�|%�K'�^,-]���-�T��_�����w���3�H�D�*���Sd"��\4����x��N[cu�������{���p��d��]�����SIg�6��F�eL�g�.�v��3r�7"���-6?�[�b�*T{N5B�_���������j�����jh"�4�Pu�����b�������r�K��tM��dH�0wx-���O���+��t5���s��������V��^�ffx�Q�}uz05������f��XF�� G��s�*��-��d��"�>�.�\�&D���7�U��A?R�6�QR���0x�~2��a�7�]�@�?���m�u�o$
b�m(LW�yq�
%I��)bz#l�2�@���^������
�w+��5��i�P��G�@�U�(��y��X�<A>A����$eL	�,��a���k����NX�G����Q�d%�$�`��}����X�#T�D�����r�	i���]t��7�����_�'�{�U�����H!���z#
���� �F�v�E�Tp��[_K�e�<FD���qr��0"D����v'�V���X-�X��Q�W���������:������f��
��|O��C|vxr�_5�H�@���E`EK���/��k�zT;>��g�^���jo��i��m������C��mT����_(�8@0�F��i4�^��PGoON�������������qq��
6�������?��)v�mR��n�\�_A6?�^��.���G��vXW���~5�O�v|��v�}
�F>u��ZQ��Q�yt������������p�u�x��A��j����sv|���OD!|{s�>���	�S>��Q���ib��N�\\���������7
������zZ?P��CQ?�i��x�����:��~�@�3�8�7u�����n�-�v<�KF�#��.�/�����7/��)�9�.S���$����c���yR��6�N�[��h�N���7
��7�3�x{p\g����sugc��<����������Q{y�8�o��C�4�����7'����@8�����T�8��@#u�Z?�eQ?p������������9N���^�9�h�����[���~��_���Z�O���G?���2�����|�C��2��O��o����@���
�����7�I/�oH��y��^������*xUoB�_S}ut�@\�:>��'������Wg��������O8a�.�u`��.�N�Wo�o�zs��X}i��uO��.;��~Z�E
X|}|�F���������W��9��'���4��+��3/o|%J?��{tz��	��4�W�����/����att���������pzv�#�����~��:j��o���c�I�-���h?8�E~���|�}�	���������Pa�����_2�Sc?���{���
�S?�y:���G����oj�����5��4M����i-��q��������W�
f���
���`�~G���/ �4�<��E��s����Nu��)O����=v>�^��B���O5�~�����+�_����B#�0�^���z3:;:lDg�����),��s�r`�g�����x5"*�h���	��8jB���@s��*���0q�#�?����|yK�G4yg?�����j���Ke���-��Jj��m���E��N=�oG
y��|�|��������.�5����cXv
�L ������F����D���E��7g$j�gD�a��J��5����
_X�O���\�_��u��A*�_aT�f,��=<=:=��,	W�E_�(B��	~������zK`�T.P ����s.��7��?���#��.�^�Q��?�/k�c���X*l���>���O�?|ys���Q���R&)���O5���~������@l %6`P��F��Ci PXO@���1�_�G�f]>Y�����
����=�A�����`K|�#��������@����o�F���`����!f��zC�l`�H�����&P$��
�k9!~	2�	��lT@:6�j���`%p�cL�,z��>��P��������#�o�C
�9??���!���qt����S�C����������������A�:[a�*���Sfy�{x6���~��a���d�<�?x��w )Q/�w��K�|4Z,&�9}y����PV�������)b�������O�w��4}H��G���s:���Xz��BZ#�yk^��k4Jk'�����7'eF��XH��'��A�
���s1~��q�_�2�������9��xT���@=�����S�,��0������9���F)j��A�����k�t5h���JP�v�Yl��c;g�#�5�r��Q�{�>��a�bT�QNPR}�%��x\;�(����)��%�����(��)�Oj������(j@e�U�O�.tg���E���xJ���_]�WTi};
����\��
A�5��H��f��h<kB�#��	�--��` ��������j�[?A��z���v�����a�:NDt�����N�<����
i���b/����W�'��+��k�������=�ES(=��{[M����<���!2f����r�U�D���K�c��OI�n��BRP<,��z�2�l�e�X�������89�>�Y2�9���E�/j��ZH&��f�5��vw��SZ5��x���/�CX/���}����'���'L/�e� ���C/�nop{EQ�w�������?�����D�o���E��{�r�t�na��rQ� �D��z����m&��g�>����b��8j���V�8��]ew������V��k��?�?�x�9�������1��W,�T[�Y��KD��/G���3���K����dL���v�$l�xD����Xy���
��U`�juG]���6�q��E=[Zb+���/e���G���L���r��w�h��-�o��Q�j[��#>�/`"43
8KK�"���\��ib"���fg�bO��d�%@X�Y����)�t6��l��[�=oh,Q�����[2�t�,F���E}�C��%�[��p�`��a/z�~�������z1�i�i-��L����_�����Wr!�/U���q�+	A�����Dv:�;�s	n��K��?���������a��p��
`\��K	"����v�*z��������+�)�{u>v8���(|�F���[����5�$�4e�z/�4�6�YY�R�_�� 3����+����=��`/���
���>�l���){�����.!��j�Pt�0j�������\
�'#��������>��)�(�P��H4���Q�u��H��-�m����"6���&���x9Dw]��0��]�p�>D�bS�^x�3��Nh�$�q�������H�I�)
�2a��w���q�a����4��+"�|�x�
��S��+��D���G��2�%���YF�KU�x��!��RxuO�o�7v�D���3CQ6;/�*HT��if��_W�c� 2��������&�M��g���/�k.+�O�L:��GR ��bf��+���c�i�;�_�w��IlHz����0���I�	#+��6��q�V�������de����;Q����c*�F��z�O��7�/�eSAW� ��]%.��y��c�S���6�,�8I<_
��=sUV��TU���i%,w��{&�����x����1�k}x����������Rku������(�Y�|�7�*���l��������KpNb)g�R�!�]J�}B����A�����
�Fa $��p��w��3�P��.�hm����+��H����=���?w�>�pu�|t]������Q���5S��[�U�������W�������'��bjW�4��v0�;1{f�")N'qI,"�J-�!�w�^DPF��~�t�u���&�(�s��pu�4�
����J1�z������>��t������P�f�^E��(n�k�0�q�c��(��CV_�z���p�t���������Y�p��������~�8��Y�(x5C
���}��bso�����33E�*�a�v�W���j��&��+�K�U�N/Y�v�V+Qj����GgH ��/�ziF��
m���<�W%��.��H&������{�
Py�c���Q9����8����!�����<�_.�pb�������u�G�Xl��^�9�T�j�l�/��-j%�"�r�������2��t��9���
�j��LU{�D���%H�V����,�o���gB��b4�3���G��>���'O�<c�������B���?���`��`K��r�	�L���t���_��rw���|�Cf������44��4�	��'Hp����^}�{�O����:����6?i�)�G9�(��R2�h2��V�
0�x�_`D����f�g���VAt���^��v�2��k����:q$���}������~�����/0@
�����i�B�al���.������m�N��!)
��y
���Uh$I��Y�u]����4K��H�L�������>�����(���DJc�yw���|A�:�_sG|SV.��j��p����Rb��[KR=MV��8�s	��:6����E��Y���a���I�#�9X�C.>cH��K<�i��@���o-�#�����:�6C����!W���)�D���	+�2I��]
�7W�����h�^?�D�
8��CH4��'J4�}q$����7r�
��'d
��0tM
�M�W�g�7�m(�:2O��A����W~�.5$��\�k<W�{���z;_����<�~?��)���u0���r��y��mc1��i�/L 
��H�?�YfL�)�w��:��1�-b�[�@��]���%h��]
O�U3��Dl�9�9�}0�[�~ZamT����)=?������e#+'u���@<�\%%�Y{~QI����?]*�:�9��`xn�C�z�zf������!YOQ�"�����n��,w?�/}�����y��������6���g�N���w^���������1��-���������U���J���L$�����K�������WG?��;m+�����
������U���F�uF�����"����/�����h+�qV*y���>(WU�E]������U���������W0
ZR8R
g5����� ��f2��<��K�`*BX��u��p�1c����;a�^�6Ub.�u�{a��xZ�B�.`���X������T��J��@F����[TU�@S���&�[��ET�!��I8���{<xf����l7�x�\t6����Y}u�X��jzdK���Z,y0�L�D0T�K����1����jb��vu�*��$I�Z7�+�(���X�|��6�����.�m�$��s���H���)1�$�]:9���T���:;zx����iv���Y3��s�
�`�n>��3��y�6��&3x?�h�ZCS]��/�*����}kc��$lm���;������>���s�����C�z�|�{-	��.��
���m��7A�
��Pd���&wn����Kk�_:������h��?��E����Y�0���"�q���=�������u��S���O�G_1��tL�����r�?�)���0�7�uS�DI.�8�������DyS���w7��[���_����}qP�����F]S�$��������K���v�*\Zz�$���E���/�������������[EGNL��b�'���V6�y�[�y�;{�J};:T-�+�<3������$��j��%���m_bI�_vD)z�bJ�����@}7�V��TW��������������R�&��#I'���^����GC����jYuc{.Ft��%��J�
��� ��V����'!�8������/ooT�r�;����m��L�>��%�E�OO?c����E���"���$$/	�'�OkvN1��}��-C��Nw]I��
�C����P�N�����U�'`��j�KHB-���L�.�R���[�;����Vgs�27E�&5W�_�c��f�x��j��I@���Q�B9���c���Ku	oI���L��{%Ru��8j�P�kW�%�,H;t#���{���j0��
����o�����w�M���+��.�v�-��t�;��#���+9��!gM	��������z;��[;������/0�L�������Q��L���h:I���Ev23+W��e�|gV��d����e'[C*���i���f�E�QTI����us�
��a�����m0��V�e/98~qys5�}����t�{�����\����n:�[�|�Z*o%"�P.5���t=����e����bP`��a�R��fgP�&w��d�	�������$��h!P��U"Zb�e����,H����t���|�����'�0,��������K��|��,%aNpZ����1���v~#Z�2tDo�a|N������\Xv�4pVx�
Oyo��<?�!�KWi�,���q��Q����>��
��>�L�Ahlt�)��������U�	��g���<��T^3��.��m:�W�0W�{�'8PIj��MSbr���r�H{7k�wy�u`�%Ukx��fF��x�(q�kM������v��Vs�������Y��F�%��e���co��dsrNK�K$��k�g5e3�5�s�iPq���4�q�2|%O;�ud5d8����
5�b+��A���T�:��AZ��DN�i<�vGW���*�4
l��o{��>�N��l_QHt�!�Rk��H� �����������<���dx"�l�nL���=�]�<y&��	������;Mq9�����Ln�P=�g�wS��x�7	U���K�=��g��
>��VQ�m��q�H�q�Dx��N�f!������8{�`�.���g����x�1�r�h��.�r9��n��37Y���to#y#��d>Z�A�>L��N[@c�T���`_�d����l��,����S��u��yuv��sQ�T��ku��V ���� SS���YJ���)c��b��Rt4���{g�l���s��O�$����g0��7
z���K��vd�����������@J�	-	��o����6o��V��<��5��\0��HO�{b�>�c)����W������P�Rb[(B���Z��[������%
h�(��cc������b�Y��"g���z�te����/���L��5Ym-����KNi��@?��&
����[���n�?6yiK�]Hzi�d�p���A��7�D���U�f�K)��)R�@����� x�T;/�2m���8�?v��H1t�t[���4N����[�>�z��s:����V�h�����`������XO��)�����x%ep-(�~�����J����)Y4����%B1N.�E���z	���%x����hB��pL��?����' m�m��5�nD�
���^wO�qk6�q^HI�G�+Y-�h�h�[���/���T��T�%�>��6�����2��SA�.E�-�/k������A�5��r@ ���nG�>���Nk��%���G���\9�Q<����ZG\}�����y�g��f�+\X����M���D�+A�����=-���2]��F���������U���7���WQ�����o������-��T��)���Q:s���2�%T�6:�����
wJme^x�f�}2�NC7NB���=U�}zA)��\��T#g������GI�(��k�����vR)����$���,C��n�������#2$���K�!/�;��������zd"4Dq!��Z����	�Gk����K���n�i6R�U�-�
J-4�����3�D�%�_���O@��$�l&���O(��f��W�G�O08x�I��g�l/��U^m���y5Q���a=a���go[lfSW��b�������
�H��d�����r�m�1g�U��}<A����/]�j���O8��d����;�L�N���2�N$z��J���h���7����G������u�����M`���C�|�
���t��mq�p_��k����#$��wa#�y&�$����R�w��^<�6����P�gQr{b-�5���!�DR������E�	Js�����3/����+���f%[c�����9^t*���+�k"^.4j8B��,��B�L�6��"$�����G���������A�)`Z�^:\������w����:Eh�SX:��������p�F�$ +���N�Hq{I��&��y��I��~�j5��J���/��6"-�u�E�rsu�*���FjB	���CL8����@�U^q�����>��pd�0Sf���"b�s��d:wj�Y�H����G`�p��\A�*%��hMG���xo�F� |���>�:��u$�\���SK�"~��:=���HBw����.��\$|�{�V��xS��!8t��T�j��`1:k��'t�RW�.�=���8���U�#@��<$%I9��������Q��$9���CJ��J���FV-EB`�by�U��|sQoaB5�gX?�%����{U��m	D���d!KBbv��=�8d*A�zZ|�M���Ah�	$�D�g�1E�?���&�D��a�3�g��
�	��D�����o���Mu�:G�W�����S��?��I�CvBwH�i����������5	�X�7��i��6/������:<}����5�����s�?�����4�9�_����*d&�=o�*:
��S�VLx�b���H�j�%��0!�x�'1�v
���4���RB���%�a��-�j<I��ywC�� �#��!^�}"�?�ID�&��j��������B�����z`���Zk/��.Y�X���\�p�@$92���4�5�%�>iF�N�j��	�U��s�-C��������1F)���r����7�Z\���@dj%���.5����K�=���JH�|�����F�-0�hhq���O�s��|����������B&3�0�����a��k�
�|�B�|���v�6bB#��0��
��F��?��.���|Qm�?D�pt�	-l�����5� @V=C���H�}�A�"{���
��wz+��zX�'�
[����q���v6���~�yn|�Upk6*����Hf��D�J���huMT��7D�#��^�aUi�WD�����:
[^3�Qt��w��R������D���8stm���oBY��p�I��-=���������1}�3r�)�����}��\�����wsTw�����c����jj���r��-VDxc�[bi�N�u��@M'�Nl�di<N7*����f5~15�M\H���S��e���$��6�g#u7�L8B��'��er����6��~�y+��"�DA�[>�:B1/W��r�F��K��+�.��C�[�<-���e�h-�J��H������0����q0����*�D�����	�	����u�ktI0B-aC�]�r��� ���flM\�z���F��T*��
����>�M5�t�"d0����P�A_����	k�
�U�xb�%�B	%L��wm��D���.�����1qx�7	L)sF����7p�����["����r��-'7Y�Ve��A���`��5�D�����W%bq������pS��;`m���'jQ��������(����F��hA�p^�x5�_���;zH�O��=9�Sp>�0��g�P���mZ�%S>�F�&���}�����Cah�7�zxuzV�x��]�E���gl�h4���4->Z
���Rd�-QG��a�h��9%��x����4�3f��6�sS�b(��:�IQ�Cee�L$��;�c��g���Y�)o����������% �f���|�#�����k��>�w�B�k�6Q��c� ���/���0�:����o�6��Q�/�_2���q�9�����v��}�5QR�B�5f73(J����-�K�P[
�L��]�-@uj�~{�!~�K�+O����Q���P�[*������`4�������\�b{e��T��I]��G6�c��
��i��������C��k@��~���K��"a�����P1�4}�T~s�4�����<������ft����A�����PD�~9�	%�DP����7�����ZFCt�Bd/�'�����f�`q9�\�� ���X?��vH���Lz����o�E��*�V*;��B1�F+#5 S���	T=��%G�R����i]$q
	1\��Q1��D�*��z��n�������Q�mh�~;�� �����^Y��o�J�>P�;1��� ��6��&m'�������^jV�����2��������d�(z_�ey�(5"}6N}B��d}*[
�s��~�])�p��`����fR����$�y���AO'?q���R�q"S|�I�7�'��������xVp�����#y���k>}�U��q��8��1]y�w�Y�o�����^���D�^i��������d���$��	S�:��%>@����(�<R��h���������m[��PH	�7������������f�����"H�B������#�|�:�
g�J��X�+Q
`�zX�F2�=!3:�E�o�T��d�;���=����F�����?�Sl>Z�(���a^�3Y{��h��^�IB&|���s���n)���}`��G+&'?�wV��A?,�(yP���� �]hP�zbsI��a:H���K`��������v��1O���1��i��}�\cZjl/R�C�C!�it�����u��7�o�W~W�'��'������m�f��|�Hr��M��n�������Z���]b"\�1�'g������G�:��E�]���
��5D��bh���/L~�tZ�����T����/Y�v�i�r%�u����C 5����e���������Z�\��5b�W�/�Ca�'���,���0��J$����C{�o��������(@[�)����P�����}{?�3n�q~|�����\����_]���g��u�B�&^�a��|n�� ���"K��YW�CK����|��[L�����H,S������&�9�
��>�+�/R)�5�l�`e�U��v�
�U��A��\��J���_`j���V�;�Q	��=�Ol����,��NUP/��W'w��_DIoj��z��W'�M"$�3#A��]$p�Wk-�J��r/=�� �2:gp|�ur�2Kcy�]+M�9�i��C;��T�%��~�%G)r�W�;���i�U)k���������C�<�R>�yd�a���4�������Y�d��y�w��p;��jEfI��<HSM�2�c��g��wc5�b���8BH����I^����2�������-�wcN/�:�`�����4��D�K�)ji����=����L�Ub��	eY�b�}G<�w����z���?��d����v�����7�C����?j���Q�����<E��So�>�]d1�Z������A�!���o��#�b��';q�����C�	w����5���"��U�R���
��/���$�e�P���,in�;���3�����V:\�c��&L�H�(��?
�pW~@A :�fO�!�+	��w*��s@O����Z���l�G
�Iu����?mQ��@t��R
zi���w��p���
x����a=+���{#�m���q��&4�	"%nTo���2?�L��"!1xD��kY��;$&�W2T��B�>���������5�k�&��9q$t�@s��������Vjr!=�E���M�+n	G�33�7���=�t&�
o�A��[s/�k�uo?NF�����Ks�����O?�������E��k�e�q��
�F��Yvn}���R��&e��a}p�i��F�b���'O�l5������!��-�d�z�]���8HhRu'�e����!�Y�Zz���*����eL_���'��	��x��l�rO�(�a�0~��~����2�n��s&�e����k���Y�;R���\!��n%��I��\R��n)���"k)����v����m�T���CE��zf
Z"�*���3�o u�w��m�����	��XT���X�7�1�"���P�m��H�����,��/"���RBk�'�����y�i�v�|������	\�L�S��H=�|�8)���YE�!�E���X4�u����a[(K���1GG�+��`!����}�����0e��_�?�1v��C�8��T�h�#����~O�b$���fL��0*;�Y��p������_>K@�����P��%�Z
&d�7���<���M�G��~?F��Y������~�+#[HP��&����F��<�0��">�n������N� �wSk��K���t=n���YH����h����K[{���soZ�^��NJ#!dJ;�<��
%�<�]�3�@�8q�c���Uh4��Gc��e�Zy�XB���L�&\���VE�UW'��6������^L���cOn�C����z�\4�~3����������a<�&�&�y��N�C������E_���5���g��nG3���S�R4���^����<�Jrb-���q���r!�<�`��,i���K�s^k~�8�GQ��~� nUq�%�=bLt]?1��Lf�d�p����c)���hY�D|G~y�.Xu��]�%n��8U
&�f��&SU9�����
�np�$MQIk���`)���Q�N-b����b�87����*�����*�M]Y����v(��v������z��
��w�U������X}����I �LG�"z5��()40���`��R{�%�s���;�X��'�4��TA�ym�_7E���X���r�[��kz`�X�XT
����p��}s�+f�F����8d@Z��@d2�L�?���p��>�M�G�[tpfV_���7�|�L�J�&��M�?��`��}�����g��@qBT�b�����0�6\]�p��6d7l�<�����
�a�n�v7���
�I�������D�����&���xDA�Z�+&`$��=]��.Y�J�$�t��?����5����"�g'��S�>F�QO D��5h�@8��;(:��S�?2E�P�yXvC�.�����j��Gc\J���3g;f�)�yTm4P2����|;��Mv6q;k�9+x�OW,D���r�0����C�&W}�8��%�[7��-6x<�M���K����4�����dYC�	K�y"����^*t�����=
���p�;+M��&�����ZVI�/��7��m�����E�J�E7��	?
N����mI�"�����fB��$�W.���*�X���PpS�9���&�	���/���i&�hx��>!�	UC�yh7(���xz�����l g���I#�E���E=�Q�hR�PrpOkS�d�l�����=�Q8����P�b^Ze�{�+�����g���Qj����g)Kwn7av2�y�@B��x�(��@m��a�n94	m��� �[�GC�
[����^��<QGXx��[��,�����8������G��8"�A�<�>)Y���s(q7CZ�vS4��E�+���@<L�WMY���}����3�~���X2Tz�R'�vh�n�����Y�0�������[S�R���
�!��:"q���4	wB�{o���V�3�����y����*����H������=�}^{�N�����R��3���i���7���-Y������&n��EZ�a^������^����*4��d��e�����|s�+�&c_ZKu������B�>������j������	!�h��J{����I!��E�d4�9�H��3u��<f���if����i�Q�X��4�Y"h����^���r]������9�28K�`�A��z�@JV��jY9��J�������kDt�2�L���*��Wi>8��^�	�&{3�3Yx;�-�f�	�]��F	-��a}�F��L���"���i�h���v	���z0��v����?����%��d��d3�(��1�RyHM�9������������t:�>�����a�)���!G��n��_�Q��?E����Fek}=��Uw/w�����������<-=Z]]����7�{��]��V�����W���I|�������=p�	�j���%������f�q�����������$ey��O���}Mu������m��4�^����J�����^���!�|&�����A}/6��)0��A(��L� ��;�&&jw1��{J�_�`��8]z�,���H�DQm�Z�M�k�P(����I�~�!�\@l��C�?���i
���������8���d.��^����nekw}������l�[���K|"���Y��V��6��G�����-,�e)|5)��_/^,|�h�Qr*Hn�~�c�N�������x����H�!�.a�� �����"������n���3#*�*o���u`Z[wwP���m�]��o��o��(�O�����fbt:��~:j~�3����f#@Xk�f�@����ZU��4%wx���~��S����C���-�"��(U*8N������i�����;b�:��j������~sz�w�5[\B-!3z���0�C]��uP��N%_:�����L�����gRCt��%y�O7��>��Wi�"������;��O�����-�d�V�Sn_v���������^:HHr�D���r�\�V�Cx���=Z��!*�g7<vXk�Y�f7����4������L��I����A(
��>L���������.)����NgX�9<��V�}`%E�\F�����*�z>��1*
9�T?
��P��Gx���T�eL�-:N�7y����EB���V�\�V��6J�-\�8��~�p�Z'Oj�mj\���C��;\�S����V������%�h2��S�x2���-l��Jm����0�(�G���!��:'q��	�pt=�n��H��JY�2�X�*�uR� �f�W���xu��"�n�OF��WV�[�=�)�� ����h
{V��*�O�w|�c�����n��h,)��Z�
��"L�0��LO���G�[;�������^Et��3����cdc1��������:~��������^p2:l����Q�4Z�����u8/��|��O��hm)a�X#r��#l�Z��^�.j���������h�]68f�ZJ4xu/Q�/�����-|;ff}���/r�e���yR
��\t�Rk�ar�xk������u����8�lll���oo�����h�S�� ���:�z	��\����F���:�_�H��3!�����U�T���'�M|E��
`�xM��������T�b������j�= �^�.�?,�UZ'�B�Oej�NYs�?���2�F����/aY���/9[�lV"����E.�]�r��l��">���'{W�jz�V��S"�=;
������]��K��
^}�~W����*�(�no���)/��8����4$u��,pn���b�e������o�M���K%w���������m*Zt�r8h��er�E�!�����$��5����T����1x�u{2����c�\��%�����3P��g�|�K�@�w�N�lTQ�S�l����N+�C^U�s^�z�T�(�#�8n'�q�y��(����r�9"���(����w�-���0�����vrt���/�))���.�|����a
L�*����G���]��C�!�T\`0�K�����������^G �I����h���V1
t�K����s���f�����E{I�����7'����$7ph�_Nj?{k�_��0D�N�W������!��H1c��l�����t�%���`��'$X�94>b�F�R���.$����j������]���nt�h0Y: � N��i��cs�Ss-���
XL�����Bi pj��(a��Ep���1}���A��(R��HU�����x0F*������C��A�p�~��?�E�'���z��Ar1���?��2���k�?���,��u,��L#�~z;&�H�LI�<M�}��������p�hn��d���n�-}��xF�@��~~9h_�C�h�hw.G�`�y�@c������K�&�:��e��
�'(?}�����++�G�}�o��YD| Zm#SC(}w�J��Ve�J����8)������ �9D1�}_?�A�!O�>�%�L��/�J�L�:���t�����M���d�	�.��#9%����O
�:�`�#�+,��Ch����_�O��*ba�O�cF���������DF~q5�f��}��t�� X�Z�>���B�{l�kMMF������@��F��<��#�^�d������A�)KKe���h�F�)����oN�t�J�������
��q�����'4��)�pUar�d�y�KnRI8���.u��F���4���)�ShO��>S�r�@�(<����������Yb����pu�R��<tGvx�n�>)�q��"��S�j��N��!�� T
P�K�������?���}�qQ|���_}8��{�D	]���*��]�A@�����II��]}�8�S}���z����]�( RB�;���f�7��o���F55���z?��������fw�n�����c����G�Nn�4],��,��J)��Ke�a�u�}��y������U�;�/s����=��H}����V3�������G�S�}��=�
�������	�l��V�y*a_i�������(�>5P������1��W�{w�B�����|�oL[�����"���B��jf���7�5���5�Tm������|O�@��B�M5����
�}������`��K�OF]��[9nuo'���Z����h@|RJ���?b�y�I����V�B�����a�a��(��q/����?`�|����^��&�f:���$���J�\	�y�����	s1_^�y�=�^�`���R����BL�N���h�(�`����>>�i�%�k�;Zn_��N���i�;d�)�t��������R#.��O���:L��?`n)�������V���s�
"���&R�l��L�Ra�b9S�8�;Yj�4G4��Py���3_���p�'�K��jp��W�VE< ������0������������V���W����]Z���?���Uzy�\-��Ylo�*���10q$��!���'gmJ�������8�"��f�[mJ���x:S��k�."m�w�����
	��Q����������
{��>G�L�?A�Vj�����q���W�fajZ�2k� �m���\v�d���p>�y������=�`M�UM{S�!��d��hL6`���N�v#P�t�i��V�NT����h�~x��h�����+��ej8��X�����T�����<��������k�a�)��m*}Y�db-g{t��tD7�����X!���'kJ�/ofz�^JUe�]��%���I�;H�*�"���-DB��l����H1uDY!$��x�����T6�p���'U���B������w�����K�EP�+��}5��;#.l@Lh�W7l�J���w������M�s�N�Uq��b����1�d#�M�'Y�G!����'�4�f�z����=
A�"�Aq�ZPE�m�S��0F��:)�����VP4��h�$2�?���5���<5/�Y����:k�Bi��E`��PT�`��� �sk��}n�4��y{g�l����$9��
�^a��`���2btq"���0��Z��m3����`���(�9��z�<l��w�CL���]�)��+"k�y_"�(��D��O�2o^��@g��WG?��6�-��T}����X{��c���w��\*Wn���L��	<CtP�������iR��%�&O��P��?
K�T �;t��>�������t&�j���
w�:C�u#�T�5�����Z��H�0V~������[7a�0�����ChA{Ao��s�F�c{��?�'�A��5p~?�c0K�>Y~��Fe�Q8 	���������=>��_[4��4 Zk5}��-��?-=y�-�G|E��u�'S��L�)'���X�������?_���+'�>�V �'r��X�z��.;����}�c������	D�����&����������`�3�.Qa��v�.*i�������E�yv���RHV�.�/�\�V�/����?7����>��]�H��r�[���7��g�(HXI�Y�p5�DV��]�D$���C��e�[���x����4"���U�����\"C(av�V-�C��=?�)������^�����2!2m������W*���
�zH�t7�XC����u'��G����=a��Tj=+:��D��p���.kb�.���GW��\:�G����$�`R�����iX'Z���?�R)Y�+����]
�������m��fw0��Q
��t��F�e���5^����1���rWt��&���*��-��d��6v�8M#J��p��G�65������qw]���#:�\S��Y�����hng��F��8�a.�����==��0����'b2��D��+:����=%Xe"[�*[0q��Z�Ve���C�l��b�M��0�]h�����a��2a��Q.U�����Re���A����=�}O�c��s�/��5�������M�Y�/�a�p�~�=��0F�:h�����/��^�]�x�"=�M����j�����V�X��vSg��i�
�����"�������SK/-���q�4MY��y.��� ]���(i�;����E\�Q��������F�����o@*y=����6_�=j����3�e����-�������i�����������"j.E�61��pk/�#�B���(���]�g�3}�����<�R-�Q�V�K:�|��
r����4{�"�8Z~��n��z���[&		c�
7������=�b>��"�O��c�
A���AGh���'1�E��	Mj1}����|��.���G^��J�d��M8.:�H4��^<k��e���N��j��A�0��np�f��������P,����D6q.-�{�G�!dY��s�]i�Y��S)X#��$%����lal`0���{�U�l�����|��X�{M��~3�(��Gt��#&#`8r��2b�%�45HiOC�X� nq��J������8��Q����]+�8��6��L�!jJNao���j�DIG��h|G��x���Y?Ag_��e��+��PD���*mo���0��$O7��lOg�E~L����_E�K
*��l4�� ���f?!b6�7��:��-�I��mP}���A��o]���[[�a�1���<%�!Jr!,�;�8�I��\�?�������������\�2����2�M��N�d�0�d��r`n�����e��s����lO��$��=K!�5�L��+�\�l)�46����Tm�F�.�R��Z	��1-�R����X�",���,}�5�����Uh���ty_sv�]����L�/_���oSd�<�2K���z��.Z}N���7��o�s���?A�^,�k��%����6��Q������D��L&�����Q��&��Z��_���&�:����g���Op�P�k�`�>1�:�(��u@��[�V�m�C�+��Kz�_D�bUX�qd,~����]�b��R$�p�<����BtQ�����K��uJ����d]�TA�ubQk��RN�g�=�V7)4Qes��q~*�k��Y��q1�4�����.�-�Ks�4���6�RZS�KC
C&�]>������z*��*9qT��������
������U�;�1>�=)E���6�!x�x�2�����
�qK}������4t���ZUX��!���1���7r���6��7���'3Zb���^)�V@�mPIA�H1��?����f��Z9����Z	�s���p�t��t������\ess��TU�vH������N����
����P@���N�W+�Fe��.�5���$�0{�,-H����V�
����-%-Y��P��Cp��Wl�)3bj���I[�}�5ON0��m��Z�����E���w �Pg8���j��OA{O��,�z
��V4g��.K�o��-���GK�1���%�a���T1�����D,$p��@�����Z�����1U�%����+� �����#G�b�m
Sg�-c@��bC�s9���g�d�����'�~5Cf"$�k�����G�����]�I5e���F�>���Pq�c�������	�`�~���=����M���}<�m�zq�A6b&���"J��;F`Z�5�L���Z��%��L��kj/������*�BqeW���v�/1^�H��t���N���M�N<��&}W��/~�wzHr��?Rt�s2!�w��<��w����8��)/��v���us)+����w������w}�%j�Q��-�+��O�^���(�;�TD�~�
�D�yJG������(M����U&g��v���I����[vg���f�
���P�t������.���)�r�'��G���V����Ry�!����v���$��I���c1�?���}3�i�tM[h/5�����q���y������xK�������������o1���>l�	5����F(������X����.W(�+�8��<�i��,U7p^�[�����kbZ�5��7�y&�������g>N\Ew���qnc%�R���s�Y7x��+��1�[��'G���n���Y���~��6s�;����.����x�Y���A�B�kdK|�%�n��Uk8���?��|R�����:|�XX����g��~��
lH	Tg�k��
2�|{�a��7�:�����-��u}�ynd�u��M#�.���Y��K�k����[:������@�x�`c#R���ME��d�����pN7]��Z��V�B����������������*�������������l�g��a�X=�q��8�F�){+P8�	9�f�j�ceih���#�a)yVJ��U�K{�����S���?P�����v+@��k���/�q�;��.�Z��|V�������v�J>bc���b�Q{J����b���Y4(@L���6{�LQ9��/Q��x(�]-T(�$��)7�#��!�Rkzk�e��{�n��'�V7�����~��^��o8��~�XO =��{��������i�?k����k���y6�Tx���J��i]P`�M��v��~��7����1g=4����~[_��$n��]�sP���OC���S�M�S��Wk����}�=��'�g�f�=4�s�{%u1'0���M���Z����h�	|>:����<<���z�^��d�~�u��eK�]�f�<��W�y0���6����������2���ta*��:����_���|�H�t�Uq��50_��);���Un:z�8�'�Sst��E��������X��'�����4��cn��E�U�]4]�-_��V����+Z�~B?L�FD�b�L��Nj������}����F�,t�D�FO��'����t��KaQ�L�b=P�ka��`.�t��	E�Z�}�"_.&�����P���e+/���t�m�U�W�v���v��C�~<������s��V��`$��Q��$����7�����3�82�-���l��-������E��2�ci�Htx+h�����="��
]�If��v���5@�������al���a�z�;��?;d}o?�9����s�Z��W=4�c������7:X\�jq�����XW��\��=0�z���M�b��E��p}���7�@�����U�Y��V�	'���d�c����G�����m����8������D1{�QS������8Y@�H�WN���^���R�!im|�v1����K�����^�V3������:�Cm���8��2���+�6���r���W�+���nV)+gu���N�_~����%0{����8:>R_M���	/�1������LPf�vs>�^�r��w(gor�����mo�ol���!{��9�+�c	��r��x�����:�2v�Bs���@���]���M�?o��y��4�g����9�SP�3�aus���b�R�\0�(i�p���	��F��%b/���	����=}�b@>�.=%����f��:�R"l}!��W����#FW�<���sgW�wgU.�p�k.�D($!��(m5�������v�<:;eJ4��XC���������~~�����Z�����<��|��'���ZLJ��������=B_�z�:��-��t���3��|U~�?�;��U5�����W[�'��A�ay���I��>��S�<@�:���Q����jZ(jZ�k�{r��<@���<!&o���'����I�I@I�a�����]L�g7�g�T��L�����������;Oz�'��J�:�*�>�����u�h�q���}�O����g�GG�G�F�+&�%�$�$�U�~'>/�����Z������9]��J����O�A���Y��f��z4���|�T���.���{�n�����N�E�����"��H/*lEukc����[�nzv�x
8�oF��X���Y
���?������7�h��=]��b��������/<n�&�����A�����!tQ�`��������.�"�X�fa�$>�<�4��h0�PfJd5��d������F"��2[`w����hg0�W���SJ��;Q��RJv5���f�S�$��p�-�
{�v.as��N�g=BX�^T�l2�7}�u\�'�:z���K��}v��Hj���D��n�.�Qz���f�V������M�lJTl��#���M� ��;�%6��^�1X�$�'��	��BB�S��T4/�`7Z��;z�ASN;���%j��!$�����fJ�@uKfmr;dC��.#M)hD�XP��P6	 
a=�TB����y���dZ�����D Lo��8�M��7Y���	/���Y�K*[#�q�-1*��y�D������J�Z���	������� T���q\{���9�w:�Y���n3J��	�5e���V��	�g�J_��9*K����wW0�Df7�n2�{�J>���+�>OaRq,
������)��u:�S���07��������4�y3U$�0�djh�u8����H��
S�!w�L�������l�����+��}��u���S�J�j�8��Rx�>��E0�0/$?��I^L4��?����u��y�h���%�Yd��g���@b���=���zJ�h[��%�Bf}v���E��.�z�,W�+�� B������$�C�&��QbP�#��%�HI���v;���k�P7��LO
N�9j�X���7�G�SA���
F���(������<�����9�S�IT`����f���Q�R�%��$��mO�noplO-O0[A����q1X��6��j3���@Nd���{R�/7���"J��x�M�t��8$�&F�R����
��	�f}YLW�FEoZ��Q�?���./Q�f�'b�����'_5��IB�&\`��a{v{�h�9�����1no+�x 	U����'A"R�~O��&�����Vm�Cr�_9���u�zS=����1�3J�&Cx ��3u�;�|���p�^�E�?�E��1�-�Zd9;�"�����T����O*0'�QS
��{�2OXa�lVI����k���1��B���!����;	L����u+|��hEK�i	a�#���\����^[z��������j���AV�#�}�	����*������C���C����6���p�Q����9�����3��4�)� ����������E�S�5	;�J�u]SBF��Q�p!�V�����c�L������Y2��.�U�h���C�����2 o�t��B[;c���v��rRI��@�m'(<VA��5�*�a1a����y�gGJ	'�ak���g���.hBdW�Rp���-N��1���NGv���Bw^�{_�L�ei�'�.�k��9��-�����En\;l.��������^���Ou���&�`vm���'9����������!������h���P_���g�O�6���BXC����������9@X���7�Y�j�KbA)�Y����1�����Y��p�{4���hE��(BD������.Y�&r%$.g��/}����J���_$t�W�"Q��XT���t&�?��/(m9��g��*���������;��<����d+��'���X9��;{�%UY�<-�� gl�X#�'ZX�q��\|��s��bs�����_?�|@B^��{:��+�Y�4�"�>KN{A�1�g�T�xY����z���Y7f�����
����&=�Kz���7�h������H@���6�,��V����u�t�e�G+g�|����T��em��$�e�G�!��>=��p��'�,���~O�K��BZ:��Yz(~����t�{����9�r���T���t�/���b-,C�Tb�;����|�f�����D���B�6�(c�j�i��FT�Z�t��]�
D��
�NC�����~�znL �SJ�ZhI�[���n�B�oV�+�m2���A��K��1U�^�6t�����o�}�����!�P��.��K����H9����F�rFA!��xawHp�p�L�
c�u�
���V@�m!|l�M�R�oh'�i�^?��X�j���p�Y&�l�r�@��7!D�l���[!4C*[z��Bf�!ww*��
�y�"��Q3{{�7c�l!�{z^�'��_����d�w����D�+H���6��E	y���/'ql�;r��,�(osv����U�nCd�����_N��|i����z\xU���4�������V���AA!��noc�"Eln�A�^���K|h/@�f�\$���5��kT������KW����Su�����Rc�\��������r*W��
�
%ju5��V��+�V�z)�z��c�_�L<�\1���$�g�`Yp�����������! ��
:��� ���"�(�(�4��Q�;4�[h���"6��4J�b1�u���*��mq����{;���� xS���k<�����C4�7����&���<zuqv�:��vA�h5�~����\ln����6��{JU�6,��&��u��Q���u�c�����O 4��6�HcI���=$;>%�jV`��I<�?��kz��1��vv7����=��������R�yt��o�F\�,"���n�Q[������V��
��mX���x���Z�U��:p�������p���Y�Zt������g��fa�����{�+�Z�0I-�����,��������k�*��;#�\F��+6�S��,&��'u���Z�^|R�5:���L��~A����8<j����$%n�7	B(f/�k}����u���Ub��o��nTz������E�v6���d�	��=)i��o7"�m�7(���vu�;�%��\��j)��[
�������/y0~�PR�+����&������7'�>��tP�S`������&�:�t�E�	�Q�Bw�����6�����8��M�K�fE�����7������i7Z�j�p�-�=����W��v���E(��i�u����e��vL��t:�>��������v�L��{������z7�d�~D�E��^e�����������0r��������9�����k��\��Tf�m��nA�X����I<]�^�Ub^���x:}z��^���������K���I{8m�x/��Y{0�z�j<8�[��6�U����{��_�����&
v2	��c,J�����3������qvJ������/�.�vH	�E>G��Mw������x$w�4�Tt;��va4b�F����#�*w�E����E~���@���W��w��t[�'��S�
y��w<��*&�qIL��0�jS�6����W�k�aI�N�>�c�
B�_����Q�b	�@��N9��q<!��L]�k�E���O�����j�A�E��2]�f�'��%�����F�>UR�$�%���\�����t?�&��L�(�
�N!�X�T��j����Zk������)�a��S-�+%d�����BwZ ��og-L��L�_8�V�,��O���K��Ri�2�WkL��4�:�����h�Z��S����AL���R� &wi �Q���8�,��=������4�8���A�����������W�jB���lO�h���<]��&��^�]d�Zq%����Av�1?�S�>5ye�j�x4v��He��j-��`�l-	�h���)���)M��F|S#weh3��}�2{	��������_)J������h+���e�/����}A�*Gb.�pO��p�`ug��Z4#�g@��[��#6�R��! hWA:<��*v����N��v�G���#���n�
)���d����3NEO���B^�����PN1ws���&�S����q4���@D�bN��b�:�gh=N�hj�J�b��ZbI�s��0����=�G�W�np;��S��4M���@���ZB ��s�ji�*;4G�U�,��k�����^RE[$:h;�U���$a9]o���v/��kp.j���a)�?Zu�sc�?Zu��;D�l������J.�2q�y�C���h^������dPy��
��1|����S���.��]�^lG-PF�#�i��D3�f?�Nho56fx�&d1�*k�����7��]�K��T�E(�E~���F'k�'�7���M�Q���C��i����S�*�9<�r���N��5G~�^9�<C�g���1YDDX �����!���m����Aw�	�&y��b�=E��@:+n"�&9��7�w�0�E� =�����
�����kv��|����0AFm
���?� ����#4~fR�
���B^�V1�P��Go��x��r.*Zk.:�j�C�?ZF����<2�����%q)?b=Qy{�,��JO.Eo�(r}���{�Y8%`tM�=i��J~������>^\eI�Bz�B����&�Vh��$����x-�)�B$T�
��,�M����e�8����\�{9��fh�cX��a�D+�=t����A<���� ��Whv�H?�*�+{�e$��C��l9 F�i��s@�7������rU7���@����DF{���d9�`�����C���x����������uP��@+0L��7�?7[��1�����Itw,�L���t��h������A�%�3�����WGWb��QFt2CM
�p�zU,j�Se�guG&s`�V�G|�$�5	��8��XF#G0b����&��s\����	��W�����$*�����Wb�-^X:x����p��yB�\OGK���.z�`����0�"��(\������9>z������x�GR��G�i��%��y-�`�&X����[�SR����P�m�3�0���Q���/3'v�0���r	~����p���5[��Ta������p�%hq@�S�v1l��}G��,+�<��t�F�M�T��X9t)�r�88������v^�hPQ�J����z�oRo�X��������`�;t���nY���S�:�i��N�X�������`�M�{H�u�����m��DO%����)	�O��Q���������O�n��qC�Ge����[�kM��z<��������\����{����|�#!�S��v���e������
G��x�(��>�0]��B�t@b�s
H�Zps�XM>$���jBGa���h|:�!Vbe�rE����Q�=���
�����I��*��5�����t��Oq&�"������]�X��F�$�Jj��U��Y_�x�dqg/�V?h��k/��Iupv|vj���A,�9,���$��wz��27#�P,Z��i�_$��&�q��M���*��E�bB#��k�������g����}nkK�u�BjM��d����+t1�'�� t�9x4o���O�e6 ��v�Xd�d�j�����y](������wr��l�}:���O�78�,]��`c1��e�v�8P����?����u�������������C�dq�OX�M{����p��j������%�e����E.�>���u�#�!���%��uq{��ZBc&��}�g����'$k
dr�<���3�����������bzcW;�������������b����/Ng�T���@�}�&�D�f�5YIbr���YSf�(/���/A C���E�L�<�S*I�������I�������Yk�S�nW*r��'�H�!r�3���Gg�6�m����4��2���7wp���n:��}��_>i�mI�����	��)/#mK�;YO%y�~>��7��]�B�����vR`i�{J*[;$�l�l'��`���T��
�}>9��>�����wfW�AL������V�&d�4����U�<97�)+�uD
��De��kp��Fv����[�yJ1�F��>������K�]����r��< �w�mRS�����tQ��8���K?x���"�o��e����m�S�����v�E�9 H4�C9��0|~+���?�w�jM���R/���<6W����I���:!���v��cwv����r�I�6	6/��5Ft�+T���)�6n`��hS������5U
T��f��0��8Z�y�n����>�����?���j�������\���<����K2�
p*!H����v�R��n�]5Y��o�.�
|����!uq���4��u�I�l�t��H���>Y~R�z��]����W-�.��]���������}��v���7�&�l��L��T���8���>�o��[�����_���SU>��K�d�Y�1��x���eRL��K�����E�Q?m�(����LI��d�};�E��x^.r���=��V�`�Z� �S���shr.�����U�������'����]����}m.B����3����a�P�y��:��_����5�h�/ ����E�������.H	x[�����^{�?��Vg5v-�d#�v�P1�j�t���h����]|���;�jP��S�����`�6>�v7(e��+��\^&�+\�[�[����ab�����7�>SQr?~���iV��%��\P|W���f���nx��"(G�/G����X� ��;�S���R�i��8��c��*LP���Z�l�MY�z���l_�����+f;�9�8����%6������]8�^u�z?�����C�B�/�{ �e�+}��=����2�h&b�J�
:���j�<\�.Xp��1^b�g�;�oQF��;�7�}g��M�}��kD��(��-��2����%������r��T_���6/j���Z����N1Yj��E�n�&y��W�J����e,V+c���_�������7FT+oln��QnL��a�`I��<E�n�\�������~~��< [��U4SQ����(����28�q,(���g]�����g\�	������=�e7��q���6����YC���9����m��!��
ek���31d�.����=� ����C�����q<����?������?��j!v1���z����2���S*/t���d��Z�4���hz��G3����pe.CQ��=���q_�`�6�KpWA�hjw�dj�������-�'N��M�5e�	��t��j��L����h4i�����1�Izd�04	��X���t��\&�q��	���^���-UD[�u{����p�Fq��T����)���">���Y����h����]��g��Y�"��Gd�Z��^�rR��OQ���-����iJE+@qqc��%J0�S��\��z�����w���*�R��������������ra�����������De�XAT�aQ���
���\v��H��jJ���<QyL^PI���
���d��0:j�����>���9���S���I�!z��[ _�(:�b����OL������8�g�L��)��E����>�����(9���T�	g��`~E���|s�M�p��TSq,$-�X��d9@Z@"�Os5��c�c�����cW��
�W�Zc���d��&��s��:6���������%:�
�N�cE��-��59&����9+i]���J��^)�B{�n�%&����8mq�e�!E�OInL��4��� �2h]�M>������9�SlJ�n��2���G�����R��v������]���U(�)
�������p��RJ��,�uz�l�::=j����315M�A�D�T��"���#�uevc�}L�&���@i�.E���`1���6=K@5r���5g�Y��a�T������3�K����E�:�1��g�oz�7'���������
��P�TZ��5;�	��w��o�'y>���$=�M��j����w4��r����N����'6^cG�+X�~�2��r��T�~�����=���n��~u�����.������[�-�J���V�hySN�����U��5;	P�U���9�����������xs�*��7�Jd��f��������[������s�u��R<4��H��2��u��rCU�L3�)�QqY=��W��|���2n����b'�|���)�����S(����a�o����9)�M��v�MG�$A���1��T��[�)E��J[u����<�o��D�����"�X9)&�D<b��3;���4�����(���y��@o���X�(�V�R��-U�rc1�:�I�#����Y��RV���<�j��8f�-u��Ud���LKR
�����!/W=S��Fg����t���*y�V*$��SE��N�
B�<�Y��.�|��O�u;Xfo��
D�\�~R�:�&�$�RVA'TX{�qJa�p��+��2TI���'����a�v������.'�d�+�f9��u]�JT���vp�u��d�Bu���ug����e��HG�6������,`Qt6\��_��������������^�8�dT8S,���x������gvD�M'e����/H�s�}������
2?4GM���(�N����+3������T���P��Ld��@����qS�w�DU�(
������o�����i
��"����<�$��J�{`<�������.�21cc-
�K=�d6� 
=:�E��yb]�����s��^������~��c�_�<]��/�_������<���8��=�4b;�.,Dn{0���;�aJ8	0�XY�8��c:���gG�rYBN�R���YC��U'*8`DAa� SF�
R������qH�������j��yy[����0R8F���K��.�F�#�?�a�>kd�:���-I�� ���
���������P�)����`1	��&���vj�$�6}�	�~�W!|[]5�C��PSt/�>�K_c��6>��6��;�T�{�������/�
�������r�g�������x��o���"�R��.�1� ������7��G���.&�m��o�|��'�$���A��:���LV-���6!��5l��HfdZQB�z�0=�8r�*
-��A�k�A�z�6�.x�NV�w����=��9\���E������?��� ����+|��@���`/��%D��S��c�� �y*U�J����\X�����V����W�����$�����r�g0E�,��7��>Jl0P}�V*���z+����TAX�X]/Ba(5�4���1's�)]{q9��UJ�����{��E������pH����'���*m�&��y��vR�^j���)�D��a��u��\s��w�,3}-!������h#��X������(��w��d?&/@y9�Q��(}%Y ��B����V���#�Q&D�jp�R3D3������Fq5`6���F�&�X�z��%�ZeE���k�����8�d>|��?�����Dz�hx��0���� Z���G��(V���C��D�f#������)F+��0�
��V6�6%(�<��&�te�d
_W�.P8��,��X���M��Dg������B���~�h,$��Ae��a��on���mX~�V����Z����h(��LK��*���^���9�'7���V�T	��'�{=���z����S�R���mr�,�4��#�V�9
�#:94�~�g���s��T��m|d����n��U<I�)�OF���������-�2VE�	�*!��2gC7O�{�W��yv�d+����sJ�a*�O���%�`��	%{�@� ���"E�eyKf:��-�6!#�b����`�Wn��Ds�����_��9Z��o3�4�9!9�$@
S�R��-�[���UI�m����F�L���[������.F��J����'�{m����a,f�f��+>�=~]}������i<f�(������ ��}h\�3�l�.��t������"��H���gy6!��$��|d���`Ao
���������0��*D���_�b�B����/��f��"I��N;���/���c/l��@D�h��i<��ka ;[W�,$s��	�@��fb�B�"S�JSj:1�5~��)�������*0�v���d������o�p����'A?����o�M�s��H��x+��Z���,m> ����eY. ��Og`�t��QU[�#�z�L��?21h�BM���i��7�)��.(`�rsR�j
G����\��;M~D-����U��a#$�%
u rP��R�cc>[���v+�K���G^4s7����q0��U�>uyG��b�?�������;|��6���v3H6����}&Hw��I���Q���oOfSDR��/��T��[�t�SY���Z�m��3CRFadn��
��&
��7:��"W��B��j%$�(f���)�� `g'�Y�b ���t��'�j39b�}'u`n;�����8,�_ �����_~%����c���F���Q��.�|aC�^r��6��OieG�6�(������9�!}��??�:�`+)�R��g'Z���l�;�q�����������������IA�^d���Mnc�M.�R�q�{�-�"Z�?j�$�_H����.�
xajX�A
��"^k"-��'#��:����`���
v��l��[�����S�
QW
WL9������}������r%�L����������=��(�_v"r�
5s]��~��"����=�����I�5����-���	�B����=��b��B�+��
��1�Q��bt���6�t�]K��U�����H��2*����pX�${��/�#���R/N�m�7G�j��\� �naU^
�����������!l>5T���S�I:��PN�eVZl�3)�����f�mi,����Icx��������c�f������7���e]���ay�xR�aM�K\�q��"�]�>����(�[��u*G/��c��%#�9-�VwJ��3� ��l�U+�/������O�����S
��/�������y���~�P{pv�����i�m�|���s��ou&��Q��vit����� ][�UB!�).����`wA�]��;�$�����Gc5@��j��k(�f`��X�^_N�Sf�%��y
��}(/�CR�7Jt{�s�����I8���	�"!���A�'����l��p8�d���o����:�%Q_����v��F����1=�����Z%��^�g�[�AZd1J��rs@�R��d(l��j��D�d�I�D1�[��"�����l{y����r����xw��zXQ��SG)��vqXk�
��"�l������m�����_�G
./@��z�e�$E� -g0����P!B�\�V�w\FP=�?�&;�K�\�S,)�{����SE3<���Z8$�K����H�&Zh8m�q��%����@�z�7E��M��Nz���}r�f/�4�&q��k��X��C�@[�T{�S�����d�{w��Z#���|o�@8�K�]J�$
t��`B�g�
�j}c'�A�q���<0H�j�Z��jQ/h�9������?6>�r��hm��H,Z����=��������Z^Wi�&��s��lY����W��-)!�*�	�8�$#,	�e���$��[�����?O����q<9���e	�R�����gd�1u� �)AJ��~/Fk/h9�u�lm�0�v��S��R^H���y�BGx��@q����)�E�?�'����lQ��
�4x�a5 �����,�{�z���D����)R��7j�����@hO��[$��G�*���))�Pp$��T%��YZ+#+�b���wO��8J=��3L�����*���NM�_pxJ`��������F���U�xpRk�@D'�A���Dz��e}�e��������Xgt��q�G��i.�MON�?��I-���4dY�iRdCw����3�rf#'�-Q�!"�/�7��M���'Gp"�6Mr���_�jW��L�p���,QT�R�����P@���x/\]�Vzh�	�������wk�����W�oN^�/��0�O�%�I�v|F���d���������8����-�9kV,{��������m5�����3:oE|��Pa����U�-�9Z�U[��������?}�4i�-�M�*�����G��\<W������k�x�S�F�@�c��ZmO���
!�g=(��b2��p>�.�`B��x��BvB��� _a�]���N�&��(,�3���%'����6%7)��&1�m 	���4�Ym*%��
H)��	b�M��-|E���B~E�W��Y������88��FA�:R�V�V�$"X�>�[uJ��=/�r3��r��~yj0��#�O��}�I������f�d��L��W	H�7/`#[G<�m��p���6,f!�:�h6t��9C_6�m�`�E���r��
����H�4��C�XL3�+���sx��������~�����Z2��+�'h0��q�����R�2�#F�	�����Ll���]FF����0>�����'9+�uv����S�X2pbO+����M9�D�DV��\c�����u����P!��,�$bxG:�����N�R�K*�����	�|��[�a���SA�B�)��Nn��?�tb��;���,��w�(P�(�4l�b������������gM�P��=�c���@�u�CL*�%��2��n��g�M����<@��7q/pB������`K�m����IiU]�Nh�.����������^�2�e#���;"	�w�r4�Mg��!�uG��aN�1K���E2�[�
{�����T�7��~��q8
b�������.:!L����~��z+)w�7��G�As����;�+[^b�,���UW�W��Q{]{�`��������&���������h���	H����<���vZHf3�^2&9�����������,H\����mZ��G��8�i��/��0���'�5��'P�����g��AFCL}X����������������*��G)��
��(j=��5j��v��;���h~Y}$��#���Y��O]�������mP�*h�=�}������;=|�Y�7�-�%V��r�sqm@6��r%u�(�����Nry���<l�Yl\����9�-�i���F�������[^pb�Fj�0�R1]m���9��������Y3;n&s�^(�|��r����Ta#�B��0�rL�^���\+N�@�������qxN���In&���p(��J��w����������248��{�Ee����,�F�#>#�5�6���3��s1?�~����8��5S|��������Sg��u����~��p
�Q�����8*oh./��k?�L���8fB��oN��|eqM��d�q���������'eW��j�Y�����|��3SD�����������WY+�������P��3z����vM S��4��^�S5�@�@�X�ssl[R�.��0w}��$��y�)���K�U���0~���U�!z�o�syc5���CM1x������Y�}_Q��C��]��OcJ2r�!��z�>`�����:�-&��j��?\�!_lt��<3V[�F��=��E�i����jG���"
�W��`���F�SX�>����������J��X�m�}C�E��h��O���������NsL�����|�f�����yY]����<j�`�]<EY�v9����b�
�?������������
	-:��-ZV��3���1���Z����VF����L�2*��2���O98���Z��v�m������</��?*�Bo�#B�r��������1*�N)��Hi���Nj#@��Y�~	���p�a2
�\6d�����X63t�.��m<OK��\/
�)�@���hP8[����I��*\�R���4r�I���$`���zS2k0�__����8�6����:���4����u��LZ��*��� w����>���m���������3�|�
!sB2��#��������`c��}�)�=����-��f�oZ) �����:�K�_�E33�����02����@[�]�rib�F��n��W��=���+F4Qi-���"�-i���O�oM@�
9q������w���L�O�����R��aEO�z����S���N�c����d��I�?f�����+{40�t���s�OKq�b�@�*!,)�-��?�i'V?�+�S��e�b)��Ln����.���������]�	J,��L�0�y�?k�
�:�w_x�Il&����v�j�ZzD.���/pQ���48�LZ!@�:�'~���E�h��Y���A���<t�;b�^����2"+m�]�|�C�� �����VK�s��~�&�_LB,��(�����\�PM����G����{�)��k��ikmm����>9�����L�=�}a�S�
r@�YOp*T�q���H��iD|��';w�;�Guk@���}����	�u\�.HK@���8����B�/����B�O����`���
oL�%|s_XT��yb5�d��A���*r��� /2j�T������H�x�Xc�����1������}'g���_����k3������sG�I<�8�����4���������t_%�(w�a�zG	�x���z�bU��Q�5�k9�Z�@�f	����YJz�Eqm:�'^����QYAJA�y�7puM7��E ��x����S��l������(�����zw�<
�t$���_�`t�Jm.w�������[���:�x��z�E]��
��\�MP�/���$g���pX����Y@L�,�DY��"���G�a��GCZ�>qR�!��n��}�=<�Cc��r���r��<�
�=!�@=�$N*'yjkk>��H@��+�s�N��w����na_�z�TK�9G�b�C2D����}a�Gs���4�vRE�?��Lq�BX)����j�H3JY�i^�0OD�C�O���M���Q�����/����I
F����nP���&6�����&l!���)_���1
8����������A]��>�%�t��;��
k�h�
,dA�3x3����.mA�s���\�f�H���^��J�F�$�"����R6YG*=����
O>�%{�9	��H��;��$&�u���\�� ����(��t;���t)m�;���uN�<�g���������&wO�5��-����Y��,�����Y�\�����:���D�������_���;9�'Cr���t���/��}�����IU��������s���b���4��)"f]DN����Z��$�"`��0>���)��IY_����08e7�0���pJU����C���m�����a�V`��8k��G-���M���Kq��m���4<O&�0����������7E�Jv��)a4�����({���qk�b�3".)!B"���Oej�,I��
J�=��b;��(�T�=�_��b��2��&L��p�w
�)��4N�s>n��?���X���V%$I�s5��������u���a��c*����6�F|S���C9���=�/�,8e�{�)�w��s�gu��V��1��xd���WR
sm��/�t��;���U	����%����4�� N\�j�F���h����V��f�&�#�d�g�����c�EN���z�B����,�}i�����{����2��f��h�����/��)i��;��M�r�`M|#<7!�61���n�i��>�R���%�8���fHu
l�z������������e�n���@�C��X6�a=������������<Q�Cgec?�#�L����,�'�'��|�d��B��Q7�v)��A���������b�5����bL%�	U0r&�<�99'u8_#)�0����)f5J�����E�jT�Vh]i��#����+�q���I�i�I���nO���Sd���n��~����h{�r�����o�n�77�Qycc{s����sZx���:���U�P���L��-(���mhD�����)��d���E�����>�5��_Hmt��0qX��D��=���DY�2��LU�db���	�JD�"j	$|'��#W��E�FV�(���l[U�L�����%H����~�}N�$����o��fj]]����8(nV����.Uz_�����P�y(�d��d�1�E1a0��b�K[�r];���2��T���7nU�����>�������#/	�piI��B ~U����U*�D����R�rd�K���9i���L`sCp~,��w�P�+����?�B�:���k��sw�-���������e���!X�'����XI�Q��FI�NT�D��N:.�G'�F�vr��a?,Vl�
j�����i��+��M���Z���q�\�P�rys�T�PO��CY|�������PI�.�5gp����	$�Lck+�O�mt�\*l&����	���N;�z���9f7?�7K��x��2�'_�}M�����+��g����8��C��M�tg�m�������o7�l�8u��J~*������Ij�M&��>f���J�K��N�B�
���Py�����b�A����7��Z�@&@!b7�emK&Tl�T���^�S��l��S�����<���KE�=Sd��K73����+�Y�*��am���g�}y;���Z�������#p���������D�_RfuO<�g���O#��-�],����_�!����.����a[R��x	�?I�Xy
��-��7�;!;��C:���"
���E��j��e�G��/h����-������j�?�9��\{8H����B�R��������8����p���\�T � ����������[[wVu[����
�B��I����:a�5U�T�����f���My�����w{ssge^Nl�xU��m���|dE����m){��Dld����e��>C�O�M1x��Q�	:T^����8����rx�^Da �V&�86���'�/M�2&��"��h�0�`,���k�?���-�B��i��_��3�w��{�����R_���O
xp����u�*8�r�P�h�~
���'
�&Ni�1_`qK�U�%��������zD�	��)���<�����`���s�FQ ��l�N~��yU��Y���Xe{e�}�8n��S�uF8I�L��[{�iZ9kf�V�c�<�:�a��L�l�YZ���j������W���?=�����cy9����!�hX�����������t�LF[rzv�hN&�`6��X�Q�\�5s\�J�����QR����J�t^������-���&�o{��#7(]�CR'���5����p�XeMM6�<��z`��3���2�2���s����K���S\g�+�D����R�&6&�+���������c������\�b�T+>p��R�,m�t�6[���()bp��Y�s��#���N2��,�!�Mb��E9���<��t�H���������!1������pJ��'�V�Ei)[����a��M<r�z���d�o}[&3�l'��>�aX����
�TJF��V�5#�<����e'�[���m6+9��U�7��]�W�wJ){bz��{���<]j8i�Z��3-w����g��������r������+���N�(����Ku:w��J��Rt�m�������@'��,��&h�aN��S�_�-|5eW�����Z���"������h�n�����2�fn4��f�K=�!�.�^�������`����/���+�|��bn*��n��K�l���Sf�������"'�����K�,N��N��
�g������WXWME��C�p���r���[U�2�t���)G��x��!�*�B�V�Jkg��a������dG:�/����i��x9N���j��	a6�^Q��H;�l#�gc(	'?Mn��4���@a���a���}H�@U�,j=�5��P�W���F���Wqx�<�L����qS�*�N��Ub��Jo�!cj�������
�;�K�*n��t��a��!�V�d�qw��vF����(�#2(�?�3SaQ���9�EYf���c����[�����@#���U���}�����D��U@J"��vu��F@��������z��K��)��;�N4��#��l�;�a��b�*GTT${���R4 ��9�^HAG}��|��mc�	�f�oH�.���CT
�l�q�Zhr�S[�,��E�ll�$��a��A��h#G�GIe)CR�Gz���<i����J��P���F�_����-�M�m���:���f9������Nb����������Rq�=���& �q���v���n�T����~��/Y��&���/ �,FK.M%\G�f2���0��%)�1EK��U�;�9'�gN��]+��h�Xtf���w��<�o�M�#���#4e�Nc��>xO���?�U�s
l�����|lw{�H�\)�6��k�t���SL���Ekk���A��W�JC+�D�E^���]�1��e�2�$wu���C��O:JE�}#��	{
�<=D�!:��d�
N'Cm�N���?x!����7�|10v$`gg��QC�������NP�L�$HDno�l� �!��}���s"�X's����������F�;����I���<O���h�%|�H�"t����olob^�JuK6������y�y����u2�`����F��xv9��������~[����2$.q�'�9w>X�W:�>6W:�W�[�^k#����e]Q�.�����q���xc!4�\;j4)yt��:��������R�}�1x�4���}���_!M[eY�F;������9�1������~'��g*(zP����C/��~/�4�N��� <B<�%��z�w����!z���C�r{"���B4W�M�4�qyW������Ri��Y*��zi�����l��o�.�;q��z�3���*�Zpr��d{���������G���t�t�z��y�m��0'O�W��h 9#��j�N�0oo���{7��������Y8�@��������_^����-X����5������S�L�����Om|���.�;�������� �`xR��u^;�hD����p��D7
06T�4J��P:98�5~(�����?X�Q�j]������KT�\��N��NcL�z�hty	m��}����@�kV�(%X�]��^���#����{`�����v���=P d'��?jC�K�=6�R��7{�%��ou�`�r�{����.�~�����"k��6����(TE4��)���._|�A��p�����sS��0�_��.���Z��?;�%�i���m��v<BJ�u�	���O�����yG��@��]Ahc�F�I�n�`�_@N��"���s�38=/�`tz"�M�d���utO��:���T��C��y�]�$Lt����!G������ZT��)����o���
G&��8���'AiB�v�Aakg'��/j�
_$Q�7����F���n'.������$l?w�$W9�F�h����N.Fh���R��
��v+�S���<��N����"�1��@��Td�6��b��d��U�U���k/���~����sl�Z�Y:Tf^�p��t�����L_��������H�	��&k��#��+$��j4�>��	�T.i�Q��$�q��e�/N��A�kS|������[��\"���y�o�������������M8���b���,����%�O������af����	�\D1�/"����w$����f�x�VF	b.6����Wb�������2jL� v�4W�P���yl���*���`7e4'i����R1jk��c�V����w���!�9��Lm����U(����eL0���nY��E�����1T�h)J�R
��b0���C),�S����
F�������S��Q1��w.�z{����N�r+w�#e�T��c��&����-
�2Q2�����I�Ev���hp{3<:�Dp�,������A���$�q�* iHL=��S[��Z�dK6iZ$���Y��� ���{$���~��z�6�c/��n�{
���!��b��9�
��w�����6������V�{�l�a�?%K��T�(�-?������b4�V}�#�Z|�����E���B����D�����H��>�	���
�J���P�O�Y�p
rp��� ��J/c���U?������N)���N<|����J��wf�Ej���3G������}��d^n�r#|�O�vv���m_���F�����|�(�`���)Fk�p����6W�eR'R���0��'���pB{��{LJS�	�������Ux^����eP�7�PR	_�S6�jM1�G��W�����BhE��~�����TNf=n�����������v�����{����e^V-@�qj)��z������
���<����(�`D�Ow��R�	gD�%�`���(��bL���S`6(q���c�0�
^��������l�6�-B0{�x�NX���L�2!��Vs���B5b	���R�9�]�%�	��OB8��3�:%0�k|c��f�5����
�F�$����L����<G�t#���+��o5��������A�jh�s4�y�rUC��c����1nw�W�	�NXIzMjj/gjd���#��1�C|WRN��Q�m\&q���-+`�uBs,�'�,BsEa��%g�.��{E�iJ�>�������k�N(���t�|.SE.��+����]���!����p���S�P4}�1I($I�����^(�xk���X'���k/�����������n�����(�/���
%�)�"��2#)��u��z��vo�l-y�h~����T�t^k~�����N��8d:0hR^����������Ep�)��p���M�
�~wN����������TvJ�����(�t�X��pR�����>V'��P���3hV����g�r�I�$�lh�}w�=�J�\*o�3�n���`hJ��ub�q�����Do�u�usn
b�R���F��RY�����B�R}u���~~Qo�O�5����Ms�o�*"�����Y�:��Y��%��9��x
�,,�Z�YO�*�L'@!��L�A������Z�����T�6g��D#w����u���
^�XFs�p�8m�g�k�^��I<T�9��������+�}�|�z?�"`ti�7HW�T�r����#:
"�I�����C�e,w��*�-���V���@ {��}9Y����A�w���6���
}��/�s�;�4�_]���B��#�W��A�o�
��7=a���E�!b�g"i������(>�*���U�l{��U�%v���N�4a_�X4�m�@sG��a�E���|>��_�%qO4I�?O���(RV����nUY�} ���)k���{<�_������d����,���x"������e�J�O�<0��K�qp���Z��l�?Fp��;�����6]�^z�?�N��N�C�IS|M)�zt(NBl���al('[���RP����-��Sc��=4����w���]�N��P:J��qI]��.�T�T�����	0�1t����1%��FNt��g<��L��N����:�����������$�lTTG��G�j��Nm��f�d���Q	R�#�ln�5��j��CZ,�6���5�Tc-1��JSNn�_��I�j����wL�8]'c�[E������M�-����`���\��!�����B|���J����������4fEn��
��{�y�A���G|���"���-���y$-���d�g����$�W����X������Mx�_8	�M�����C���j�J��������%u�0C�*>����	X$[h����>p�Eg�EY8�6iv��^i|F�}X�����`���G ��,_F�������?��<s�u��r����jzj/�l�f-�;��t��~>cy�MV_�nK^Ret�[�������?��gwI��0~�� ��T����Z����tr�wSK���9j/e��u�D��~�9O������/�^����q��
u��p�K�	{�M��wk&Fk���?����r����������[�����F�t�M��9��^�]{[:��Z��s��4.tq�|o�����p�q��9CXlO{���wk�w�*f�w�4�R�O��4��CyF�����yO��ol���'J��Q�^�Bv!xH������q��S�+��Z��:��O��5�mv+�ws���X�+���v\^_���+{���X��<&mU����Ru3ZE��-���vU���O�����X(oU��%�-�����xE3�����z��^We��?4���t����GCn�!�v��\�����K�:�
��}e��Df4u�����t^ ������u���P�?�c��'=��}z�RB(b���T��������]�rz��|�y��� =�:�"���Q��u}��Q��,�����@���h�C������1�[y��v^���'s	��6��������������������b�i��k43�V���;iO9�1�J��h4�F3t���U�x8(���E1��K�����t1Z�C��L�rHo��U����g�|�]�?w?wDVvB�z��t�%O�X��M������/�A��;�k,���G|����S�9�p��k9����Ah�X���=�m���;z�bJC�����#
������j�&�&��t86��^�]�R�V�<�k����a6�6���<��&����)\$�wV��;��|��U��&^Tm:}?�� +A�&�^��3�{L��
Q���
p��������)`^4"A ����`�0&6�h��������61r��/���\_jS*ZX��SU��P��
�yn�m� ���4�g)���Oh��#N."��f�Xb�mS0�D�n�_�'�6�1$�����)��CF��:9���H?��*+:F���dJ��E>�HE��=�N`� �:�c������������@k���*N�����4���;�B~�z�?��'����j��@j4�+
���Ui���M��Pp��+H���.���F�����M�eI�t�wRW�����(��d:��Q�U.�G�������}���LHD�8S�X�� kA��@0��;B��/<�`�~�W>�$8o�qS���%��4�z�=j�`��|�:�)�@���Q	�	�P�������u�5�#\��k�>�3���`}���`y�*O��e��/1
���Ou���/����b<�@�B�*9�\��j2�]IH��w��U&�M~�.���%5"�����S��H��B+�/�� ��fP�B�F�y�A6DS�C2�?z2';^	��
<��G
��4�){}=~�~�^=���0L2% ��S�q��pF"�s�������r2��Vq�z6y5�TeK��t�����X��lP��	������_p��b���1�}����8�\�c�3M�1����_�^�(zd�y9��%��Q�{��B�I!���v[�Q-������S.'/a�y��K.��
�~5�U:?������	�|��,����K��,��a�
L"����VL��0�e��4��A�hbi1v��Z����/�F_��mO�DO�a�y��S��U�r-p�������5���>N����2�+�Fw�RM��)8�ENK�[c�-;��J��(���z�R�iz���p`�Z:���E��w%#	����D
[�e�����Dhag�z���w�V#��
5(D�i�V�F����L�QM'E*�L�,,b��H;]�������L,c���#�NS���L2}��'���xHlYL�Vl���4���0��U|�w���bc.,'���
!g���*sa�
���g���,��;���A3����q�`Yjo����xcA�g�>����|j�6N�"q�G���wme%c��qY2�-�7y,,�������b�,:�����L"yw�!�D�C�4��M3��6"�0��\��;�5O
"��N�!�;����2���eS���_ax���B���]�]v�'�9�k)o��b7*�����e
��U��;Vm������q�hh������}{5���������R�A��i�V"F$��m1�����T��"/��V�S�b��4)�S	���:�2��b2
����Ck�pR��w�	8X�6`��i�������vX#7u1������&���Y��]
	]
���� ^z��� ���������Y�@f%�'N�Xy���SQgx��Q,�Cfo��O��)�.�.&FV���ph�#��e06�q����Q����������u��I����8�������8~'�Y��F����efCK�����w|��t��$N����MH��/C�6��_L�7J���'b�p_8�O"���4�$Q�-��mX B<���=���mf���^���5�/$?�X���>�BW��[�q���0�i���'a�����b�S�8np�fe�p2���6�����g7p��P��Ah�
��������n������*w�*���ZP}WlmP��'�B�R<�"�|?b|�h��A�@�'o�%RQ�(��
363��FC�d���h�#�V����Z `n^��!8��,#�o��*�%���K-�W����7���J�=:�g�!2h�f�6��C�!E�E�c��f����0��Z�[#��J{�E���(~�Y��&�q\��"���-I����3��#�����UE�c���1����i��sm��N�%���(���I�%1Hy�K$�"�Y_��b����D|;��lZ3JQ����R���K��&�9�u��XYu��pD3�]��B�fJ�m�%�9\.�"r2:����Kmv(��DeL��V����D����)���b�4�"V������=�UI�JDz�����]���O��d���(���A�H�1��#CEf!OCa��#������f������j�Hy4*���uG�V�C����+�$,IW��7��Y��tv3��L�t0s/*���n�s �k4�^)�Jt4M�����\�8���u��x]��H���P��{
}�	03^��Zh��=���*~Ix+G>���8s���KH��`�-�'�����rN����rY}�{k<glme������CA����.(�.8 �E`-�Ax���&H�0�6������)�Fb���Q,�]I<�����a��7XI]��c����&���S�@!�8�`�y%�.��T������8�p6��VDP�`��x��bvYzV�t�������Wg�"r�(�a��G��0�����p����+
1K	���{y��L���l���z�.rG(�
��c��b��$	)E�!��HA'�1�j;������vW
�`����_���@�"z�� �z0�(7�\$�,��C��2�A����W,C_ ����8��������c��I�-o�(�w9�.A���R���V'��.Z����4����D�������������l��������)@e�,q�N^U7���04x�k	�c�Yx!��������)���������yUcz���$i��.?�������K����J�S��}��X�QUWn��/.`T�ZcZ�T�[��rx�L8�%���qc��!cO �������V�	�g�o�����K�x0����bb!�t������Dc���^�KL��2(,,��kt�����(=�Jze��$1:�~5�&�z����Fnd�1�����k�2@�Bp���{�RM�B��k|�u������}~ku�z��P|p^�g]�'�f��*L�cV��4�u��t��	Bc#,�g����b�A�o�����A�m?l��c��EU�R>hL�.D��wc�C���`[�X�&H0L
���	���3����d��T*���)���@a�n14���@��|�"���n	}���A��e�@�d��w�/y�?��?i?W��d4h��)o#*���� �y��L�`��u�`���l�C�^��b�N��v���r��_��j9MeT��v5+�k�J�����Q�<���5:���)tA����D���8uN��0�!���-<C�T��{3����{�A��0s�cT���
kj (kA��L��`e��.!]a�N���,^��s�pXc!���o���C��������n�������}�YG^��6�6&�,�'/�����'���]��:��O�� �L������+��e�L@5
��~�/��#���,��bhYA&�:�z��?������N�u�~�9�3)
(�g�p+���Kas���T��5)p������T�t�X��
eQ{���J-N{�/�~�_�P���\
�
yNZ&HXY��c�M7��T�W�!tB����myflb�b�e����,�M��E�.�_�9��(���W��}O���}s�8�:��<�t�Q�'�f%OtLJ�y��0�T�VRT�&��,�o4*��fHk��Wl���H)��e���x#o�u��������_����)��Xe����7��C�Q�oT�0��vl5)n8�tL1(��@�(��h�F+��VH��Z���TFM�j�Q����.�1SSM���;FS/��/��a�IiH�����@Y�N�5i��yy!;EYM����i9Ov�A���y�d����~��n����6S-J�FU�Z�X���W!��e-��$!>�/rbi�87c����E,kqr��/Pi�0a�����PE�(������z���v�D���HD�65!��H���2����C�q<a�+	�D��7�(4������ba}&����
4��@��5�rU%�)�S�z&������1�W�����E3���K�9��s��8�%���fsi�#��J�r-q�
[l�2�_��R��eI����\Wd�9�(��%"��_�����d���N���K���34�H�vq�)P	�b���,�p�du%��aAW�5����#��$���6���wO�9M�����&s�+���<��+����C2.��d/�l�����,���;t`b�S��T>���qN�~��=��:K����@���@R�aV`�+���,���M./1y���%D��<ad���%�,>_�kp������I$q�eiv��q�v�:2�<���4��K�<-Br9kDG�4���;KDG�����w%�����"����^���T�du����;G��Q?.����7#(&�ZnE`]?��Ao�\k"
.a�xZ�v���h������MC���)��u��Q�}D��G�~��x�[C�HV"�c,����2JjME�D l�J��)r�d#h����+B���:�h��%��M>(�8��������b����
�^�S5���#��cK��zEf�������C'��2�3�J(-p�a>�'����yU.5��c���d��S�*2��:]I������������A����2��l�������i������p��|�>&X3p�a�a^.�����J����Jk�v����K��X�
`�!_��C��p6���)��0>:ej.�~(5�e��	��.%��H�t��4�p�j��mH����=>0��5.p\(`+Z����:�LO�X��A'���+��`����F�����u
���������W�.Ua=���VPR�E}�-�!OM_^�|4�>p���)����v3�1^E*��1E�	�J�+{���y������SSVx>�|��V����w��w�wOv_�;��.���]��k��������l<�����!��b��Ra��Q��}�	q=���@�eV�w�����StA�$���F2����jDr�xy%Jr��*.����h4bo���������e5mI����9�Pf���"�>XI���t�������|Ju�aiW"�������1�z$�l��l�	���xkP*a�v(��{��rjR]6iM#���_Dh�o��{}���3�e�AW	���I`��HBPI4Z�����%�:��.'�L������|��A�@��3}����@��� Z��[���9G��)i����:��e�\ @@�z�^�d��uJ����	��r�'�8>UWLuL��<oHl��M���p5XG���d�f��p6�[�B��A��0���Nf/��H7���,�
�2d"�*��_�����?�>.=�
d�m�>X(E���,�%����.���a�H�#��B�(�a�&V)����\��br���������S��6���Fa3A��b�DU5TJ�	���I��1�����4���wS�_Y����aX��)�WD�i
�|T}�Q6�l��O��r���6���XO�Wp�������bW�"�*'Bg���V�k��2iQ��bi���?�m��2�Tr�e}�=�R|9q�
��j�E:o����������x�1�FbS�B��,�JxL=r��������5^�	�M1X��U������r�F�i���Y��J�1o��L��B���dk������
~p}�����P��%�;wI�l���K:v@�;��4C
6MVu���$f	�7 By{s������,�*��V�;%��&y��e��w|�tx��<���y�B!�rWS��F3��F�qp��4�Y���_|ST���j�'�������$a��-wUXrvPm��_5�$�A��I3T�)/�F5�m�����9�uI�G[�$B6�F9 �@d��Q�t.F02k�E�2S�H�uX��N��Z>]>""��mC�/���QQ� ����8�A�� -B���^�����	_$wD;/���kU��fjU����l�h�YoU�u *,����Z0P)�����{�����}%�&�Q�,����������aXMM����>�<�s�a �P�+r����e\r�������	}8HQL���_�Q}('���b���L�c�X8�#ad��eV�&L
-�D�`�_�����b�"�a�BMo���� n��r�t��|!Y��r!�kkn�$�4Y�s�(��W�tr�]�%�S�L��}�
!�pr��W���t���Z�������g;v%zevy%L^+�$��0{�h����k��sX�R@�A�Ohm:����i�+N���/�Y�l��%xi��7�1����+L�^'m�lJ�d�V�����a�n[^k�[��i�����D��`�p����)W���~�?���bD���Q�u��@K���o,za��Jo:�a��4.(�m������.FDv(����B	4BC����f
`f>����+J��>��VV ��/(l.Dr?��&�b#�
�1g����"�r����5(�.� )�G���(�$��<��1D����u uM���!%d.
�6��@Z����c9����@Eat,�<�/�������[ 'A�k4�E�%o%'�����`5���'��L3�*�X%V�]bI6�
��i���;����~�������`8,|����X�X��,�dE��I/�����e�-d�
�j}�����3%,*j��Ncc���|�
��\y�����W�������W�Kh��D��M�zR������8�N�M�(���"#�
������XA�^����~�^�-����OS�!��0�*����^	���zf)����������6]E�_��G�(�T�H`�Av�C�C)VB��L��z�k��$�b�2���1��c����L���V��f}�v5��a���y�
�\9�YW�2��@���qX7V�)](��Z�rA��A���80��m�r_����:a��l@u�Nf]I.�c�h6m��d`����V�6$���I�!���E|����	�e��"��u$���?�9�+!�Y�����&p�� ���G*�ts�l4qg[������\��N������m��I��|Y�.+���a*NFZa@����f�7��������J��*�<���<WM�`�����8/�~��qc��.��B�p��c�"��f,T������1K1q���eH��1N����f�^��D���lP���^b@V�F�������WW�!G�L�3xjY�������8��%.r�U.�K�&M���+�R���@�,������Mq$�Z&���U�5m�~&����EN�N�Q��V-�+��h�8����2kZ�cE�W���a#���ph�Z\#��b�i��e�^��(��xE�n[={�gq
��5 q&����	f�r��N�R��k=	v=��!�7bM���.��hL�}y�b����n6�J;���l�A�J���L\�%�� ;I��9_�!3���A�&�3��������	g�������1K�xG8��%����x��=�����#f��cH�K9�=2�!R��������7p�P�)e��8������NB��Z��	1�oeZ��|���T�����Q(���\�,v|��S_�s��f���=����r�������)��3�����W�?��KAPOAa�{�I��zHv�>'�,��9�JP-pQ�a d�[yX��+6�+���*N��%������g
j�x���s�5(Z�5�����3��`��0��p-���1�<	4!���Lb�5��"EZ��H���SX�����"F9E���������C��w��AyT���%jY���J�2�=Pv,�-�Y��t�R��g4�f�4�(���w����\��p���,	�m���][6�hf����L��|�KI��6������;������O����o���l+$P?���X[��w�?�7�ZF�{���2���9��H���B�n���&��F����3>o�k:`!����dx~����M��X�r��'��D+FS�L�r�]];+'��A|��Qw:��.vpX}����vvO:�����\�gCw�*
l��`a��V��������Z|R���D.��a =1����xE�T2�kw��{����_^����+�BU����[xUZ��	7bO%��/���(!��=nM�G���5g*���7�������������}c�q�������4��Bj�0`�g�I��#W��k���(����O���r�b�
�����u����w��6m�3�n�{��S%m���d(5?��0�����>"?����O��?l������C��X���+��xS����������L�H��
?�G�����������0���o��%����M����Fy�����MS���G�37.$��������NY&�MZ�6�R���tA�F_��H�I�I�~~�a]^�v�����_a�F^�����M-j+���Z�
������5J_�5���F��=�����=0]4=E���Jb?�\���f��2��-W��D�VV�,��T��A3T<<J��"I|�L��c}�T�8���
7v1�Q�4[a�X��e�V#Zhk�M-�-�8���9�1B��Br@c�a&^�����T��m1K��m���0�V��5�	(ci�oH�4�M�3M'6Om�����V*�Ae�)3z+�R|���4�E��ca^���>,���g��J7�m#�pd��j�L-p$���'��>���!C�	��[�����@��#:>��*Fd� ��Jj��o*��M�m_��5��]��H�b)&�)�E�I�$sC���Q7����h�%��;�{��6_��2����:P8���V��`n�c���lv,�m�~~9��je�C"�G�q(�%r��E�K-r��p��;��M�>�b��P��'����A��j��A�M���-�VU�A�"�R }��)=V�g@-J��`�E�H�A�1BYQD����n"�n]�`6��*��=.8���slE���#��6&RY}J"T�%(�����$��DOY��`��S��~������i����.�+�l|��h�X/�_H�%�_��de��UB�^52J�x�iXBi��2��(��l c���I�l�Y7��/��������?�y`������V&�+\�L���f�i��f��
��Q�8�5Z��$�o8�����0��b��0��Cb�}e���>x\2g���+��"2�d` .F[7f(�k>�UTx�th�S�E$�-D��Q$�5�������T@o4�����I�~!l9}�(�R������^���'��O�B7.%�$l8r�����ZyE��/.������z��j����}<*����*I�B/��D� hx��AJ/A�����G���H�)x�%d�[��g����Q���l��-���,S�`��;�JiX�����W�5�TP4�@���V<Wn�l�r���p��|�1��,�7Z����'�nry���]w<��f(4R�9�{���8�bC���z�O9���x�S�`+,(CG7$�������:�����]Y|��\����<Fv���4O��|F�Q��\�����N<�����{�Y�0�N�� ���&_qZ- 2xWo:���b��~��9�@�G�8�-��
�k�`BJ[p�&8P�"r����b��_���_(H�L��*��Y,���|'m����y����w�d�
�5(����T&(�1��M3����j4 �p�;�p:��e�l2�+�[��
�Ba�b���v���ay����n5@	���7@(iF����S��b����x���Q���u�~����AxZ(`h
r���L'�kg�7�^h�VE�!�����]*����P�K���qW{���(:��s�%LA�I��6<���K�I�X��S��:��D���
V�to�T�>"\�1�\�L�0������I�y���^^M'7�8����
G�D���w:�5�58�Z���r�hGf`!����*��-�Ap7�n>���V���G>�����Ag���Ue����gR�R�D<�k�"���X�Y��7:� 4����G�2�������6P������>q0��e�A
8���.��c���(������o�<.�L�OG�x5��*y��$c��CM���J��N��g�WQ,����b! ������|�_\�w(;Mz.��_��3fY��!�k"�������+�^�1uA�yO�8$j��;��g����a��/������5�5� H~�A<l����_���^�p	��W#�|�d�u	�1���f��p6|�O��HH��<�8�3;��B��:���)B�r�h���m��#=�\P�2T����SI�����G�o������r2A����z��/��aq�|"�>e��Ne])�x�b�}66��,"�^�)���*M>6������^�!��	��|��iw�_�U����#����������OO0$�$�J�R�9�Qi��k���a��:B�k�' �������{�.���xlWh-E��\1nf����J�$}������i�#�9���2fq�]t+���*�|�8��(5%��su+$�	���#�
�!�/����b�X�X�^������6���.�k@
g���d�tw����QT�/�������N�
�N��� f�v�T���We��? !d/`��>.��0I�L���x�N���6X8p����ZP�"��LP���!\^�G��Fe��J�3z�������dv�;��S���d���?4Z;/�wNOY�??�t����&�T>	`�x`���2FpI���/������D��?������w�(���/jb����
�CG�������!
��k�{T�
���*��H
Ze$�����Tu�%�-�+�d4@c���)��������\/�=��������C�O��
����:�����;}�c��$����i,���+�mO��p���NS
Z�e}i��rvse�O���|<����!�����3����UT�*�-�������Z���
bS���Q�x	P_�#�����3L���4K�4@T��Xe��F���{�!C��O�J��U���;�)���kv-���h5��F&L]������F��L�MyQ�Mya�����,7��Zn�)���-7��Zn�K��������[�-��,[L�l1�!/b��c;�sK'��e�	�#�
�����.�������.�x�Y(�p8�g9�;�w���w��w�����M3�&n!m��F3��U-�����A����'�Uc��$*Q,V�R)P(C�=�"�\*e�.�Sh	v����3�D;���n�� �/������d<�,�����V�P5�������6��w�!o��������&pa�VK���#X�D�!\����U�:�l,Ed�+i�[�;m����P���G���o�g;�h��j@\��/ek��tMXa����'�&���Z"�h*_3�P�8�_����Fk����S�yF:���f�W���19��d����s��~�5��o6����82yV��w�������K�\z&�De�~Q����W*A���g�M��v��;5���T]�l\�X�S��lA��1��Og��[����������
%����"��zv��lC�0�[j�MP,����Ku�b)1�
,�{�<���\�L1�0Sw>�N��'��U�R�r4L>->��+X�����r���@��R�J\>�ch�J*�H��w��zSJ��z#K��1_ghW�l�@�%�k�a*�V��y��U��S���Ng����z��R�V�����e����"�zO�I�����jr��}d�$�G������f����!���#2a���u[Q.��[��F�sG�2o�����1�b|���2�B�7Vz�E��V(#Z�PJ"����>��4BJ�_p���D3c�����>9�F21���cty*�+P��8�S���]Ty������z+=���(���%��tv"��r*
��5����� ��G����H�����[t?�
�GO��}��3-d��dH��y��3�F"k�m���������T�$_�E�yp.E��w�v.��P?c��E���
�X1����v$@����L9bEOO��a�aWc�O}�I��U��C���,c�t���al�=�o�i!Y��W�m�0[���f���B���B�%g��k�LL���3��v��k�_sar�;�����5���*-X�Z�Fe��,6��%��YV���(Y��Fz�t�|�0�/xm0�r*>�8���svy��f����E�����}�@p����=>�%d�X��U`�h��'F�� B
��u��f�
o�����R�|�#j
�%p��W�&C�!�H�a���:|�~���:�<�Sf���z4�|��);`re�W���*���/�����3��MS
V�^I�s����Q�2 (��t��'��X'�	8nPXh"�SF����V���)\$�[nm�)��	|�������2�5��E��/��MK���	i��s���A
�v�y*��O�E�M��w��������v�}"���@������`�bb�re�5*�#�K&�C��3���1o��?g�T:9c�Mj�VP�,5O$�7�a;���������l�>!�kDUuAU�Z�i�<�4(�yOF��/�WR�*�yB8:��Yy���9�]���GC�N���:<�<=�G>����\/n����+���&}RD�d#i�f��4rv�ji�c���dE	�����Qy� nYa�m�u)b�A����Y����KB5��@=fB�����V���)E���8���������g[�����\��n����H�&#�P��u��i��N��`P�+���Pl�1�Y�#~�!�XX�ujq9�$����7��z"�!)������8"���a}�"���i����6q15����S�c c2-�S%H9��3)C�Ge�3�|���Jy�a�f-g�� ���|����0z������� ��:�|�|��oD����r��*���rDO�b	TNA>w�>aB�+�C2@"����p���f��[�)���1{!+�b}5->L��RT]��_����nB7u�oqg;�/��~J`��
�� N�a@k��A���x6mH]���*��w%ve���6�����:�����f#�46Z"���F���9Y_����������#��S�ZS^� }����x"�
���j5����/��k��9�
>�	5��s��~7�
h$����Mi2
�CR
o�8�b�R`X���@��qnQ&;�LoH��)�U�hJZ^4qm�Z�����y^�R;X�bJ��J���Z�0�.����{��/�A����`�36��}pLO�U�!�6gnc���&�	�2?7X��(�H��������!4���m}��W'y�p�&$kllmW��}�C��67�P;�
A�~�h������{���~(k�0��y���+�bI���h\#��fJ
<�B%�9�d#3��&����I�z�����1���W*d;�#\Gwk5(l�&YZ��,ax��j\�QE���]j��	(
s3�X	I�h��F��r��^y����S����;���F��76�����F0y�!�2Wk`�R0g`��AD�S#��%����X�O!�V��!X�����,	�?�g��
�a���\�%
@+F�Xt��j�	y(��l��5V�B�#n)�y��EL�K
��%��PX����x�l/�;�vI��\��y��6Z��5�"�����a����E^%��H,,�8��%;����1��'Jho�c,n����#��0m��Y�U�Z����/��<�:S�����L0oCg�	W��q�������;�JR�F��Z9�fe)������z��)��q�f�?Iu*�vv_�����G�P� ���vjw���$���rA���4�TLE��5-��n`�T�E�JN}f��vT2�Y���F:���y@��S@	�L��2|�%���Xw��������H/���zL�2�o�i���-$V���J
W��kX�8F[
F����Y������o��Je<r-V��6FBb<��Q�|�9�7�)��������D�&�3�4\
O�P� ��kp��J5�e8nD�^�����+-F)
p��z�^��+}Fb`?kiy��^�F'K�B��p��mp���hU��*4}���B��\$������`O��
,��u����t����a�OF���hb����������-�t�	&s4�7H��_�� x"ld.1�~!+��
�
�� �:PD���ho�;�����K��m��3��L�Z"[�)��~��t�<55�'H}3�>S~������gc��L����3���ke��'�F�k���t�y�P�3C>]����`��eRy�F>��`5HV��B�dmB����D�|)���DU�{���_x�P�O��N^'�x�X.�N�L�_���������P���O����Q5�B��0m���LS���!\ ����ndT4��n�-[TSL���b�@>
e�@;����F�����G�6���L0��p!@`���`�����"D.�f��8����d]�r.O���=Kh��9B���<<*�B<�'B����eZ��i"��*��m�0ay*_�d�YW5�K -��J���H��Jf����H���|�3t��(C�f�B�������8��b������/��� ����1��.���oF�����Co�vP�KB�'�Qbl\2�O�c>��A��@����
3
f�;���t~����zK�B%�h4!@<W��] @���D�{=q�+y�_��+�Th�i���|x�Q��������|�x6�_
^ ���&d��ZO���B���rKL9��
��L��������S�5��K��5��CP�3�o5v8��`��F��rT*��7~��	Z�Lr�/x%t)%)���*p[/"�.y�+����"��D?��$�ZD�o�����8��(��{����X������k���v�j�U�u'�o��o��+M���y0�-5��C�f'
�����C�)��UU�����o���$2`���]��&�n�$^��rt:�y�"���{��d!#����ElM����9lZ����Y��Hy������nP���
�d�+�v���)����Js���p�]�&���,b�g�x��i��D���g�N-�����"�5�i[����9��k-J�i�(V�J���2%����Y�! 	T�$5��� ^��0��zt�$k;9�xZ��e=0;���6��6��>����<v�1�]���.t>:�E�v��I@�q`b�oN��'��]���i����t���Q�
�"�.z������
�V:(�L J�;V�u��Y(�"�ZW�Bc�1U��t��^y�,�{�&���!�ebQ��O���GxQ��*\�<_?`L�F���:��B���{�u!@�V��@�"�T�]I���#�dN�*�C��%�[]�'�55�Ds
�����Z+�M�����M�C��������H/0�=�C��0�9����D��q�9(���T� /bC_��O`��B{y���1^�'�K&B��D���E��F�I^����� ����ol���!P$?�P}[����f,D�C)V-�0�b$��nxu���-�^�d�+��j��\�a��=4���*O5���k���y+��6/������Q6��(`�,nx2��\�(,��&������yP����fOmp��
�j�cpk���k9�93f�
�@�-��Ol8'g��CF�)��M�������b�~� �����W0�8p?(�Ll8�k�D������eX�
j�vL���`��jX��@��J1�{��E�J�nw<���'�����_M���e���=���/��)m�`�A�\���]A�������aw�3���_�Im����R���-���-����fOtk�M��������u�L����r������E���2��Hg��A��C�e�8q�Cb�6
�Zq������R��j���*�5��d��R�"2,�����������������`��������x�����l��_��;P!H��a��������
}�'(b�rr����������l���{o:��*���\.R�{�-#�|&.q�����^a����� a$e.�E�f������j{����
}����
�yC�1�[DBt���Zv�����5\(����3m$�;�Q���;����M$aS�<��6�N����P���k����"�������CdY��{�����2�mx�����%�Kp�d����yu���������N:��F6u���5	2���
���e'������U�s�L,D����u�G!�`��`�;��XRw��gL����uAK
n����0�gwT^3���tj���g���&��R����R�����^J~�V�� ]ej (W��g�4��r0N�%H�%0�/'���*�UY�1?�D&�_����r�	��Ik|�3X�������z{�
��?�5�y&��k1��+�Qif��Q����a�D#���l�3a���M���v�1�)����~�QX/���#:��XC��Jt�8��!!,%�4�-"�X���,nU��@�"l4����i�\.C@[�c�����0�� 1��	RXn0�[p�'���`�0�ay�-��ap�/�o"tt����D��q~�����Ez���K\�������x)����*�E��Pn�G����"0R���%��!0�%�
�|0��$�D"�����P�����'�?b;xH���Ug�C\sM������L%�/GI��KRI�L>�#��Z>���x��1��������/N�&S[�y�������/��2��\���"��P��+c�8��e�4�(9cL�M+��~GX�/�..VX��|���#��X_y�|����@��#�����e��="T����d�,�� W��5�Zh�
���.������3?]{��C�~����){O�m���crH�����J����xH!�!Y$8�3��������W�����v���}�9��UD�/��+���9��@������m�O`���[)�%�kH������6q�Q]����G�k���>Q<8�z
VE^�!�S���;����~S���^�>��L��zMI���1�����#N������:%_GCs��">v8������h>zn��r��3��A|����	o#���8*r/X<������aE�hE���
	��ZP�(�[�Y:ag�X���o�:?�r���x���_F����,JT���"�?�j��&�R������~*���
����T���e����d���}��#��5��8_
bu������F�H
�
&b�3�0,d%T� ������P8��[���'v���e�=��;n�au���`���`����`��+�||O]q��<K�v!�j�~�����maI"E�3�$�Sd�&�_��9�I��]�:E�+�O��*�Z��J�S:�*��^�LF"��P����J9��Qs��
�XH1������I����������@�c	0�6"��lC��7���LO�B�
v�Xp���I��T\64�}wtt�|3�Uk���%���h���^�O�����
�Q!�B`�;��0bR�6T
[�-o��X3���l-��V�f^�.�������#lj�>aS�z�i���
���wO�~�=�6.,\�,/�|����=�
�����
O��_x~����	W�2n����Ub��V���9����q���I�5�������Z� �������$+�H�B��D*�B��"����=��r�
�zZ��>B1��BG
�n�XNN�L���W!d�U�Y��
|=��
t����?$��v�TkE��A��9L�1\�+hwt��_���mE��0�����A��i��D��>�ui�3��+�0dGY�1B�0����:�.���}I����a����:;i������X0t��3��9vw�i.���l��h0����q�	�T�U�[���xJ\�]p���h���r��M���NUTPI�j�����g}y�F��+��p�f6��z�J�V4Hv�h0<;c���p��'�����x�����p�?q�'�z�|�^�8N��=����N��k��jgN��:����7Z�G�j5k����r�V!X��V��be��Q�8!���x��TW�������\�F�����N`RT�+���k�W��|�le�s�=F������j�?/vN���)������G��o�_�O��?~T^��G����}���N;'���#HT����}���v�*G�l��9T:�D��O�U���=������������.s��Z��h�������'�C0�����|��}��8���{�;(����o�H��#����W�a���? ����
'`t@
��F��Y���==[���<+��h����Cd����n�������|'8�����C�������\T���������]�LT�i������3�Vc
[�r�A5����/��W#h<K"O�B>��B@�L�u�.Rv���w93N5�Q��������7��h�a���
W[=��Svu�3TfN�����dO������������Z&�����Rdp��D���2���A<53/��	�>K3M~��j��Y�k�e#����0�_��/��q�F<��h �d����m�����=���rh�)�"Rg5� S��r��E���0uz#�/���,��LC+;�� ��h6��V��&8���s+����?{{��I���������)b,�����V�:z	�el���VK�A)��x9��FI��B�Ye
@�� ��_W�A���l�^��"�@2ZQS@^G38$��Y�7���\(�X�=��N)���{+�02	�#�Z�P0�RNY��x.79����o;���?� �O�������?���H�� ��������U�����k*�����]	��n;�TR���k�t���	���l����k��W���~.�T@�����0�J���i�P�q�`<;����7�94�.���H���0�!iWa<}��UgFx���PlC��������������S������&�=���1���E�����^�DD���c��������jy�n��Ww�g�_�y#���o_y}���m��7�����/����~����7wo�oJo�|���o�~���go�}���T������)�y��Q�K@>�^�_��o��)�Yeofo�o�o��>*���������y��]���B�h�����G�7r��x/5|6�Q��)~������Wy[�� `������H���OL�>��08������#��[��:�D��|������2�����_��7*MT/�{�G+o��~�����z����@U�;?����GMcqa����>|��2��������+��U`�7���zo��E����3��v��|�X i:�5��W������p�F��������B�������T?������z�y�MoU��pW�l��g��(��w�����8���E���]w�)��f�4>0��_���g�q]��]������g��_��|%��S��Z���r�:g�\g�3N�k�i�`��n7v3c�*�J�uBM��5q���Mr�����!�Q}��@��{E��a	hoO���l5�x4��w�XS��F����=]��`����?|�K1�����R*rz!��A��������P���H��j@��i�4���y�;s�w���	d��N�3��1���7�Q�ID��D�`��4&��: ��	�&2_P.f��Vl���L����}&(e5$?+BVHZtY�s`��P����';JYq�I�-Bi�&g�A���[�8��jT2�no��q�(�\�9X�����VW���;YM��@���\�X�9�Q"L��U�}�
�}��60�4��U)������G����S}o��&,�%@0�+������
�����"�M������=�N��}<��21��1o���ba��"K�z���F�p������-+-+��.�D��d2*��r4�|�]�p�-g��@���f����L�3_]��&���XfB� ��V�8���|]!ko��
UVV
C�pg��;�����sxg��S'x7��wM��T�����o�`	oG�-��N����f�< s6ti0�����3���*��U�L��@TE
�S3^H&��R�[W��kc+(��x1�BN��QL �����h����s��,]�����j�X{�VFX���F��]����-��,��K��d����P�6�a����6��F�O�.�Hwg�b�����D9�x0���{c�|�u�{�����ta����h�F��C1�������;�yc>���������z��Y�y]2����x���]a��n_���/�)R�����^^��}��%��
G��Kw����3��X�V�
��Z�*�g+���������"��?��'��+L"Q��	�1W\T�>���~I�G�tw���������S�����?�������n�%?x�����{xM��Z��L���Z���
e��)�X�.n479O�77�4q�K�#|�&���qz1�^2q�X����
��/���?������O�������{�����iGD&�O���K�����XJ^Z��;�:�����&�AALu����0<\��^x��j�Xf����-+�M�s���W1P�y%,\��`�o.����p�S3���T�&��� ��l2��e��bm�D7�����b��!�m���t�n�����������r���[����%��va�C��.V6F!^����"pF����*��x�2�����F��!%�6#j���B�e�� ���E
�&�EhU6�E����{Tq�D���@�d,�*��C#z��-��J�r>q�;��5�+�%*j���Q<�4Q� ���O�i��n����b��AG�qA����1Pz��]}:��x�!�7���*��-0zE~���O
��!	��4/���A��t��B�v�����f��
���gT�Ry{�+4�B����o[2�R�l&�xG9���\�g�����Wb�<D��KY��D���H
Z����^d�5���>t�Z���\/��AQ�G&��j*�Ehw���:9����T��u�]N�-��,0�=���K���9!���T�&��c������eM����@z�S�q�Q%�l��/���������D�/�j�N�X"*���Y}�1t�|������[K�XXJ+����CV+����d�:C�)��(�`�'t(��*��C�(R��3�Y�h�N�N\�&������1g����f8�[���lM>�0�u!:�.�I8|>F���}���?���t"�3I�,K	���+����������������r��5
9�ST��m0���%J�4GST1k[p+ _#P##tt�kd���\��BF����6T�[��r�u�-����K,��Q1���03GU}������f����t���^�l5Yy��hU���J�]����x#���������0A{Z
��
����BU���e����0��BYT�>��)���X��K�$���BD��?�jDmR�:T�
#�I��f�k�K;M`L�6x0�*�V�/���T9�BQ�y�n�z�s�>;��Z����,Hb�0��P��~��G�i���p��A���"���Q��������wU'�$��ev�W���=!��0��G`u�z�y$����L\��1��?�SnKE�e�Lf���h�|�C	�L��F_�"���Q�E_g�C#������?��������i:Q�r����8���D�U�B�p�f�]�]�iv$�:���Kw8�����=��Y��/�1#���"=���t�h���r�4N�_���3������*���u{k�L���[���Y����]K�1�1����
�����y�I���tu1�5!b
��P�^4��v*��
�����z�_Z��d���*�����v��2fz�����A�����QB���%h,�
4�e��*���� ��}6�O���XX�*$�]a��@O�rXF0@��J�/��_c�n�? ���7���N�UWq)���p�5#�����������58��MfEl+� ��G$R�����V�+g!9���Dg^I�#����(%�I��S���$n�(��hM8��(MVV�T	�Y������GR�rZ%YW;�2���cV����x)z��S��2�j!K;��i-5���\g]�}��@�����^u��1���:y���EUU\W��!	b�MaX�����AR�
�U-P1A��e��"���:�)4���&�w~!�k��.�nh/������T���?�����w�^�R���R�2�C�"�����F{�~�u�e�{����u����z���!U�	gW�'GW�����o�����apPVK���7�"�W���j�����pp���BETV�d����:T-����P/^���~��r���c�g=1�dU]{��M�G�l
:A��6}���f����_�#�Ii�5���w���|0����hZX��#�d�����V��S�k�+v�;mv��A?t��s��1R;�r\���)�-���~=������1�����*-*8�	KmE��,"��d�^C�{���2D������j�h,�f$�������r�9P������&���]��Dao���0jT+q? ��sL��7�~���y�n����	sx���!V����VV5P��2��\RF��o%����Fa���)��m4*�:�z[���-W=I�7M^��p�A�����m�
9u�{wz�1�^�����������o���lc^��OT��8%��\|��1+!�9�u�����v�v�6����!/����;+h�������d7j�pr����J����.���(�;�,[��S�c��������x^C�8ff�c���`!M�;�a�;����!J�
��0h��z^��G�T6���e	5�D�������������6��A��Pb��n�n���������\���jq������2u!F�]�����nW��Bm&���> ��f��c���WJ��H�w�1����$<��l����4|���qrF�����#jd4�_�CJg�IZG"-:s�hh	Zs*����Hc��z�v
��5���4+�Y��,ac$�D������G��G�9�^�2�4��*)]�1(��'�N�7���>��m�
M���v,��H9B����s��Q�i2�UU��H�g�Ng�X�*�(X�|�WL��A��ce���)*�)���������eYL��=�����EQ4R
�a�b�������Q*�I��()��=0�_$Fc��P��F%�����O�6�D}���D/.Q�`)�e`x���������e+b���49����b�b���:!-{�u�{���lT�n�7&D	����7q��E:ht�7����6�z�V�j_����-O��kf/&S����
��{w�ef����x���0���/*r��t��W�1\D��\�8M�^k��h-B>0[�����R�(���b7�E0�h%��h�z��4.�����j}�k>�2��&f��!�j����6H9�=�{cm�c���E��>������X�p�����^!^�����]�UuGV28���P��_�4"Y��#���b�K+��/����R���
F����w�y\����v����+Q�.f�X�\����s���N��O��������^��M# oo��gs��"._��!����;y�1X�U���Jd?
����n�4���Fp G\^����U�B��S7`�����+�=�A
�iV����(�!������R��u�d�&�4��`�!����2wbCV+"Ck�8��E�������G�a�y��^��=?+���=H�6E����hU�Ly�w��]up�������I�&�c��a����"�@����
��$������Qq��[�Js{I=]�	A���/��L	�x���1h8�
�
;�Xe���zD������q����c�.�{3�PY������RA�J".�c�Z�_��v��Fq��^�vK�}�3��r;���e����-���S?�O,�����q��-���V���ug�|�	Wa�'�5����Ddp�8�\^%8����\��
�k��V���9��H���H/G��!�[Y��^�D�y�����f�Y"W������0�wd%�����%Z����v���p)�����o��%o&�����y���/��;�3o�1P�:�����T����GQ=bk�?t5������H�a�.�}�/�o����<�5��*!^�������,^2����ag��wtx�)r~�OI�3[��� �5�y��[�f�~�d�:��U�ip�!"�@��X�>�������3s�J=��5DhE������92]����t�����A	C
1K�%w��������_�<@�tur�2V��&e'����a��f�����" as�_x����p����G*�����k9Z��j���3���.�R��(RmI� 18
2]t��"%#�X����k f0���a���s��l=���MA�@�j�m��R�������j5���{I�3�B4�Nw�xT�W�Q!dO
�������1{5��������{��;�*�����x��}�G�H��
�3���P��!8`P��q�7��(��z��>�jO`m���5h\�W
��`��.��:��.�lVC��:�&�F�Ui6��N'�����T�`NC2����4(�*#�z�`�V��
����m1$�����kz�S$�0���^�.�TI
y���=z�=�=�D_5F�����N���'3�)it�	�����vV�Y=�Y��H������1+B]�.����.��=H��`�0��x��G$t��T#�d���� -�`l�U������jSE[;���)�xr����,��f4��!�aQ�6.�p}���D�f��I11b������bf�d�X���-��3���7���z��������z�Z�7hl5�i;D���(������.b&�z����F���F�U��m���2��h4��S�?m�'�m�����w��%�\3|D��������@���O���x��?>����5;������A�V���!��)n��+���C��wl�Fs%�K�kpK�{Nz�s���%e|T�����q��P��b�j�J���=9���5�r�I����26i��\�26�r�������q����������$|��#j�������J4��4������������4����I
]N�^wv���{As��w���qt=���vG��'\�Pf(H--�]Z1iGh5[�f���l6���,O����� �0[����������@p\�b���}���"��U4����������x���C+��.$j`(� /#u�U��c��R��4���Myql��s9�(A�t�he"�I��D)�@s��$���$�����L��	�Ke�^.����&i|���H�eqR/��z9xi.���&��\U�������DG���;����!��s]���~��y-�*��d�oJ��U`�	�@w� 0s���K���[�fP������v3��7�$
x�$Y���+�`-��&
x�&WS:&�]��[N�`������g���E�.��+����`�N�1�N0�xs����/8b�">�HH%{��	X�O�c�~���r|7���*�OrE�@�y�C�;��������3v��J�bG�~���S���S%��t�6�K�*��z����L���)'K���ml����Zm��n�zN���`$N5U
�P�[>�9�_�������*I�z��2�E����d����g>������$V�g��+9����K��Z��z��4�/�6��"r3ACo�px!������.��BI����Mg���}\����
u���tY��N��5���l��d7[
�3��CqD���1�/a��0p\_^~�a��4�!������&L�-���uT	�u���S;j0�V=�p�0�N;������7��]�X�	�u�in�M��[T��<��Z��i�?Q�"��������U��q~��PB��&-|�������d��l��h��ty��.o\��G�=��I��T��mj����h ;�BxJy�Q��a7���bj���=��b��1#�v��1��r<����������`c?�-�v�k(bEdA���FF��P��w��%�@��a���.4�=
sp�^'��POHO$��;���$�{�6�,L-�{RK����LeI����I!��L�Q���g��d�gR���siFVM��4���e��A�K��2�L��!h�����'~��L<�IR��m����n��%I���i��z��Oq��
|�K��5�/�8������a��H7���g�H��$�*8��%z�`�`��a�`c���������(��
A�X@X^��+�Q�[��?���C�����%�[��f0�vk3Y�E~��C�h_��u�q���i�s2���6H\Gm2�y�F���Ok������}Q/��(|\��J�K� q>D� gD0��Ycz��7��7�=��`3�=��W���S��4F\�F)����H|�����&���'��X
���Vc~*X9�s5��0���vjdKY-5K�NN]�����UrN�M�I9����D���K�$cMoNkM��-`�i�8��W/�m�����Fm�������%O���n��,o��+�=��������D���f�������������+����M������d�4K�fw.`��=��&�]��Xc�`t�75����^��8l41!�=I�q�:�z�U �	�5i��L���k������)%�zrV7b����WZ��
z�����~�b(�x���y��t��$��P����O#z������	������
7�
FA��"s�ls��`h"���������(n���X��721�S����q�����a�"u��(%�������	�^|���#��ZX4���Ab���M�S/�v�Wp�D���i/��V:$�@��0�����%
iI9�:�p�v?��0"��v[�O�m�C����f��/w��;������>�I�8G����3�8v�\l�P�5�������~���t��#d��j:���h��i�v�I��V���o'k.���p`[V�V3ymGKr���#o����f��fB=Y)�s�������=��c����$OR.�0�b���W��|
���#E5�	*�A�	�!����9��3�8%�H4�-&�il���H��@U7/J$F����?a'�\��w��V�	=�.p9����������Q�r��2m��Y�Y�F3U"d�Y�.�"��I�%0p�H[�����m��wO ���Y����_�}����]��^�n����wy�isvq�M�b�U���?6���Oc�i.��O��������1�u�cK��	�c�[��ue��gj��s������z�;��������g��g+E�M(�I�Nx��AT���t����7��}�,]P���i�z�N��PTD�x�wt:�������F1��xg�|#�w���Q��<�TD��n���V����s�!/�;�'Pct���xu�
����^�A�80��I�V}�w�C���g=U'����h�H
��
A���3���/U����v���������_0�HE>;}��������{�)�:�?��wez�7���TD������W6�v�b������vN��:������������A�Xo����u��Q��w"��r�'O�G|����Q���O"1	3z�1�VD�� �!�������<]A����@������P2����)������/��9Z�d]���z�p�^+"���\�S�RL�c������2�ADU+��������<.�)����C'�f�]Sy��9�S�l%�KgNg���F�����r2c�,��
����0QY���B��A	�����*�P��*2�i�+SZ��]1�� ����hT�M��"��"�:�����H�]���)T��<��y�������a)0 ���1�`����+�n;I�������qr����?p�hU�\]������R��Ph���p��-��2*!��:����<�_�j��K��:�V���S���dS4��7��TO�3�s�����P�����o
P}���O.�&�p��9����a��|WuO�O:x��������/�����F0
%�('Ck0�����@.������}���V}��'|Ry�1�����+�r��v2y��;-�����`!�i�wO���0��VN?�9�T�*�s}5�:no���&�����hy�v�u3�*���E7�?�BDOj%r�C�
[�q8�>���U4X��'2c-�7���(;��)�����~�#)��!�:�=o�s���K����,�f��x���(�xx�v����Z��tr}�1Da�>������)����)*�+��������h���m<��ZF��$��TB������f�V�j����~F�]�HQ�E)�S�J'��H����>�+>��-D�v����`��Q��*T�����@L�_���*���`��
@tQ��56M�����O�.���?� �gz,~bb��n�t����+[��M����C�P9���DTG��^?�o���K�������{D��l�z���������mfB�c�e�_�b�X�Pt~A��\0�z��PI{P�������\tC9�Gvvl4�k��g�}}y�'�]���x!Y��2S������a�j����'#�pM@1��H���GE=�,�yA.D�������f8���'E�G�P*�rG���=� ~�>�|��������������K'���/�����
a�3NO�mv�=�O �M�EJ�d9�����h�+b/wlcN�@��Li#�1�x'�������Z�Y�ol{�i�/k���|�l��b�lG�	@��{���/�B���~��v|6�g����l�7r�}�y;]�n��<���bdQ��~�^��
l�!H,�cO;��6;<z�>�����B��Z����U������2��z8�P"W�{�zb��s5��GG��������.X�-�~�����s} T�x"�Dk$&�Nw8�����\^���{������9�5Tq��A�9��.6���uhO��������/wO�����c�����L(�u�4������t7��Z�=;��z^��2@��/�N��Fg�m4���3��pHQ~�}�����B��%�!Z�`��|���
�s�����	l�����~Xw�x�c�}������[�����>Nke�����}�[�$�z�,h��u���K@��O��{�@t=��l��������]"*�R�U/u�a�4��cwvq����?RmK���B��e@n��GJb�-h[��������5�/w;bQ{��������B��	�������g�;YQB�Q6�����QT���&���\OG�\c��!L��
��dz�mO��`�cE(4M�SK�C0x�0����I�;���),�3�SC
�xb��h�A��bu�h|�%�����GNp�� �x�0!�fc�.�
Z�(��MS|���������iK��5Z3����>������W3
��`��i^'�!�}:�rPv��&�T3n�aie�\*	&� &�]����"$�'&��1��*����@�������X>"ax��V"��zLwo������:��aH@?~�d	����V&W�n�Q;0ij��FL%8��0UV��5��`H��qb3�?������U&d�7�i~!�����T�L���G
++;�i$��PB&��Y����b��o`�w�w���7q�89��e�u���@�������)��8FAWZL���vw��7��HP�1��[��`9J2.JO��� 4\�N�vvOB��axU���0����Y�h�t�s=fz*1���&���J��u��
��k29���5[��:3^�7Kaf�R8D����S�jE��o]���z��	���+�����%o�D��`hIZ�%T%����m�F;�O�n���]����]�,d�����#�e�C��
��^�b�����+�p���`'�-K^��:u�s{�78�FW�������o�\*��{����J����.��E��R��2�jm�q�U4�Pc'�[�x(:X�CY�����^xyD����!dAX��2��iD��l��~�QT�����>�B���'g,eP�%BfV��H��c��U�(��&����:k��9���t)B�?y�k|������/��`��9����FU�9��E��(f_���9��1R��� �S���	�Q�F-c��$7lV�����;�;V������%����9	�)?i�(dEDg�-f�,��ay��0Y���BR>�`K������2?�'��r��g�O��Kw����#x�.Y�'��j:�L<u	����uw�5��Z��f3�8_�{���A��u<q�?�����>T������<�1�`��e���_��tO��������^�k2��r"�p��o1���o��z�����?����:0l��`WL��N�g���Q9
 f�� _�-ei�f���\�����ax6t�7^��q|X+��o�__��|����q��F���/<n�)S�[/���p�}��T�����?������������d�p���]L�C��!����b�k]�hTuBj�jL�jd�@"�t�ln��(mnZG�4�b@���1X~�09����'�!z�S�=%@���{���
�c����&�]H.��F���j�2��l��.��>w@�o"����="�5�G���	(.���jV6Y��"�:J	����'{�n�W8%��t�v�g^��i��sj�����hM4���}.����G�UYu��V�F�R+[a��]�<���^%O�C��r�5(CF�����_�Y����C��p�ds�:���.����h4��h�9<�FJ����To/�j�Z�W���_L�G��S�A_;:��[����d�����q�!��\���d��4g���l7��i�_/Gb�hW�J���"�v{��o?�J;_TG�}��R�ii���K�������Y����i�T/FOD�;
��FC9�%�������$]������Pd7lP�U��V���l������
E�i���b)@��L
�I\���TO�eL'EAhL�B�I�E���Z����w����J�)GGm{�������=L5�c�N7uHD���s��w�v�?:�'��gPY�[�J�)cZ��h�q��O��������<<��0�8w�y)��"o��KR�
[���O�_Nv����&�s��+i�K���Pt�������}p��=����o<�����U��H�A����	2�r%8�m��Y��SLu�"��v-ma�y��6>:
�� C�3���!�*
z�0��W8hb�z\��\
?�f��J���r|�c)�����j�P��I���$4BH�	�C^��1�TH��7%��z�Y���9����tU2��Y��4������:�� ��Js�	Y��OHV��+��7Rp�JuW<�J�K�T�����b���&L?�<�N�R�����Q�u���f�����jp����;�r�+���M�p���Q��D����>C��/}��v��������&@`c�Z�[��A2���:��G�MP��O#������9\����������x�6�B�����SE�)\��?��a�p^��wt����c):w�g�A����9�e8	����8T��A��t��BNVvW:�1�V��qM�+#<����_����os��/����
������s�I���X���
��w%�h7��&�W��8���Z�������1L�Q������0Vpu�)�n����l���(�gSmN�Y��O������JGE�X5�A��!�.G��{��7H�O���e<r�z+NU�u��m�j5��u�l'����G�T�%�D���n�<�ErQF���I�|",���wl������b��M��B��~wt��W����s��,���YdV9mv�5Bm������:G�:����z�>��Pko�}z��p��=��&^�����G��0�9����/y�4��3Qg?Q���R��<S�q�z
g#�X�p���	G���
CwT��x���3�Z�L�6��Z?�_�M�j������n<�#��f��z����V����<l���r��p�i5)��n0�������� /��+�qr�����/x����YJ�|��
��2�p��h�������w��V���Y����~�"���N~;�����j<�R�^_b�W/3I+\�,�����+�����q;K������C���]a�_���[���)7����J�3�g���zqtpp�K�!:Cb�8:I%4/����^"����|L5�����2�<T��n���rT����,�u6��?�#'����22Tkr�u�^�
Ey+7 ed|��~��fl��|a
4�f�5I9�����2������h�0���m]2L9���6K��\.��Z�z���Qu��������c���&�eMac�QSCY�~d���}���jv��e���A�^�M��w�,�[�1�KT8��4r{����w�,Z���_��V9�����Y$d��*'��.{8�7I}�v��vrv�A�x��A^��fT��m��f���v��<�&#|G1B��	)�G�TQ��GV�*�*��!��ieE�(����Xr���`p�f������
�����:>9�k?��d��y>u/�D0�R�J�z��C!C]���Z���0H�����h
1x�>	��������w����D�l�j��676�5����G��*�K�T4S��Q{=yu����{�]���t���1_�b��1\���*���,-�/�Kk��~������d����NP58�;9:��84[����[��?�[�H�oy���O]��|�f��Pu��I����X�fQ��&-����IW�~��q�m��b�(8}������j+DyU��}V�T�[M���`At2�x| *�f�q=�M���W���:|�i����	N���p]�a��gi[�k�:�������:�����9���uk)��
G��z���x�+I��;
w�ol�9M7�FhT��������cq�Fc!���uPD��Sj8����.Vw���(BW����R�V�NG��Pg3����a��������}��"?�#-�WG�W�\����,��]p�O%l�:����	�W	&���@�*"
'�|���N:�##��ZA@��]3���b��]�`�����`JB4f�EY#��3��������.+�+������_����9���6��J*�x�T��N�%��p�d�G@�X�>G{w�����]85�D������{��i����.M�Z/�����Q��{��fs#�����(��_��ACK��u�����^o��`,,��7�Y>3��r(f��38�p�y��V���>�+[��F�0��H�$7����}����qP�(,A�1w�Q"������8C�r�"�7��;g�i�j5gc��nn�q�"�?�B���GP[�t}>�&\�{�"���{�gg\P����>���&_���p�8W]���w���
�t�s���E�=@��:M��.gb��:v0�����`�7�sH�g�)�]�K��A��0��[�N}���k�z��z�f#��� (�kr_���������������C#V�vQxT����������J���}����_>2�hP��n8�Kp|���h���:�������Q��9\����SlsGpp}K�e�.��������;x���>�G�U\C{a��#�C�@(�,A�+1{�Fe�vk�9�.w�"B!�m����BJ��\����}��vO;�'�r���/�OD,����v���s��l�f;� �'d��<S�P�f�|:��11�o����y���K�����;@\�&�5)����}x�ip��H�D��O���.�M�3�z{�U��~����������c��������=�����Z�`��-��x�W�a��{�-�s���C��SV�����L�&6������bE�~����%�V�����w+@y��9�O�\<��Uc(p!�4B/��~���SOh���K�/�T��\}H��)�Y����E��4���}���IB���YA��.g�"��>����V����1[�[���|2~O�[������S����*�������0�����o%J�48�0%A�WV��T�B��vi�oh=G_������w��ET�����^�BO���\;�e}���w<��^]M'WS����������o�E�r8����z�v�*$�Y�f�����h�}�'������5�g���S���Xt���=�F�����lP�h�LC�$y�auy^ L
�V���x&��h9\�e/S�EH�p\��#8a��u	�Fg�x����*�mM!�7��Q���~�+�
y{E!|U!*��t)1��3�&�0*/b@������$��-	5HX5�^uGBg{hPZoE���)�TTR�������EO���tk����S/\��q��A{q�.�2eI�����d�A��e�V*�kt�n`�����^(}O.t@���C^��?��*�M���~}$��������o*�A�����>C������B��b�y!��������V��H@.�Vg�o9�e?�����brV��h�������z��E_���Hx����L�h&��TX�k4"9�������|�����)i�9�����9^V�;�6��;��&��7|5�� ���<:D9���P�ob@|�}�i�����E��PZkyD����<�~0��Clc7�=��u�����z�6�t��Y+�������I�F�Uq����-&tR"{2eL`�!��d�n:!j��
��d�TYP)\�>
(

_���]�������W������.���kEA���y��kB���P�#@�O�6M.�zA�K���Y�P�C�
��'��p��txXZ�+'R��_q������az�vVB�e�b)��Pe��S����`h"�+�\���i����ZK8��
��� $��S��#B�B�F��A+k^MWf{%&k?Qu(~�I���P�9�;=6D���4���)�(�\�A���1�������m�
�<��e�!�jV�R�3J�xJa ����h�x��U
�s�����o�u��
��F����-CN>���"����f����8d�P$�P�����'��)���M���`P�h��'���[~�5�\���>T�{��_a��8�4�Lh+�1�����������'Z�8���3b����#�U���������l��Q!��i��;Bo�b`����`�"�2h�q���gah'\|�
�&�2�`O�-xb�Qa��^X� ��������H}����5,�b�+
�HuH6]��~�0|2U)�tL
�����MG,�Kk9Q����.C&�~����j@��{��(�t"���y������+���r��h��<�����E6R�p(�$���"�>��5��O����|������W�#�i/yS��e8Z��k��C$��,WYvO����;�
�YHkN�%��*����{bK����^t��K�~*Bi'�D.��'����O��
�BM���k��i������Vs�=�i9Y69@�>G!��*)��y`wvy>
��[%�$/t>h�Q!��t����i����GGU���=�y���/�����':yz�~�]���:	�\Q��{�������'��n�X��;%K���_W��V�>��0,�D�bM��O�=�""�5�H������+��:�Q��������W�a�A��������x���}rV�$����%=�z��|��B��t��8��#������iG����Jnn����iJWx �h�������d2�H�C�~Ktm���]L����{���A�>=�)�������-\������JK�;p��O��[
�wc��JwUY�B+/��
w�W��4~c�#FO$���'{s�i�%i���:B:�FhW�ck:Cx��%N����)F��x#\w�-������&��Vl��'��|�A�sfh�_�G�(���\��'���X�1�H���G����*<��+�?`����#v�N����0��l�j�����.~5�1�����f
�P��H@��4���<��47�Z��\�
��q�*C���!�x��A�kD�q�8��h)�(\J`�a[���B3���S�D+��TzL�+�4�<���x{S�v�jrO	�*�*�B"`#	>�F��\FB�jR��RF�p���~Ng|�G�����\x�D1���A��p\����}h"��p��s������`!�R�K�����)���c�+	���D�S���g���%�B(����WK�ZA�p��	����������I��;��E�����B�t`�;<=V��q%:�?H�IfD�1��8�+��G3O�.��Bk�U�x$�"h���sS@��w
<�w���
�������W��F�4LU<�*��A�����~Lu�(��t�0��-`k�Hl���A�n#N�4"`!Km���XWkK]�iJ�LJKm9%��:�m"�*P|Z�\7Z
�����r8��\�������@�v�c`e5+q������4�YxWtvI�K�(��T�1��%�A����f�(���PUZ�J��f���O���P)t��S���t��S��`h=�J����/�H�G�R��6��-[S�>C2�j�@�[S�!j�g��J=���2�K�^E���\���A�D0�MC�������0�kdm��+�%���`U�],LFS�X��N�A�i2��!�7B �M��dMs�6�����;���!��'�����Q���{b��pNW�b�[�{a��\g����j��Vk�J=��!����2�D�W����eU�e��f}���������~;m��=� S��(d���d��N��g���M�G��hF��4�b�������\x:��Fu�/�w4������w�������b�7�dYP����q"��v�1`����/�)8��h��������3�oh�x���'W�q��pk���b��b�����7���z�q��5�[
 ��S�RF�C,��\~`���F���G�[��#��zx����2���[Of�|����T{�/�����_��H������U���K7eW-o�^m��|;H���2�������w�9��?��Z���@���^����z_�w��xZ�g!7/&�z���=�C���Zg��C�21��u-�}�HtQ";o�����a��������3$����������tp�������s��SU������RkSxMP-@Dp�f(�%S�������zg}��h�b/�9:y��{���mG�/)��nO���#�6����i���Q�9��N�d�N��IL>���!�p�
K�������}�������`� �J����(�j&�=C����!����D&���O��9�@}"�3=��L'�������]��I��[onmr9x������G'IP�4�P�����_���N���.F�����T����y�5��
[����o�qN���%{�|�������x�a��
h#�y3��)�:�t�P`�[l��Z�\ U���^���F�����_�o������P*/��$����>��I�DM�\\��cVw������i�3g�w���#��:[��M~+�z�C�����������8"������xv�������S@�
b{����������B���G�\��jyx��h^���=owv�v�W;�p�Q���INE���~".f��M����ab��X{TNG��D�Y��fy�hf��o|G�sA��2>��g���w���6��6ev��"�u�Z���t�_�j��aD^�zr������������\��j�soh����'<Tr�^|���(B���T�����=�	����rJ���x�%^����^�{\
���Z��T�7�B�n6*��D��������B�T��������Ap��P��j[�����uc;�1(�k_�e���Q�����3C�NN��bPZ�-���V��9��x���m�+�����_~A����!'�M������������������*�0e@��Ig�
�����>kl���2��u������xf���X��<���H�Gc�=l�<��������Zm����m�q?�d��<kC��mF�^��f�Q�������L����������*�����*L�o������cj��3c'�q����[�%�:�ky�\Vf�����
-
����]�(��E@���l)���!'�[�3�0�='�]�C��>r���q?`��`���������s�p�I���Y��i��@u1F�."��	S���u&�
����(BbN���!;roj=��s+��F�X�sR���"��{l����ec�z��0������Zk,s��AK�����Wi��0�����Ve��\,�7��m��b�=c��Z�+-�en��L�����
��O����
�CZ��������-��B	�H�D�Nv�I�GjB��5���
���[A!�������Q�k�h��� 8�:@��A+��K�K���(	�&�������!�FC��������5{s���A��������G��o��\��������G7a�Z���x	����C���e����ZLk������{�X�������Z��c�/�N�B�E�b ~6��O����I��4����������v�h��a�%�O~-'��7�J�\Enw[w�^c���l:���O+�� P���L�F�f�OG����q��	�L�[�������r}0�b�����7����*�~�Pa������a���*s��/kx�X��o���Ac�;��i���������9�g�	,�a��������[��]3�hk�i��+����\���7v���?K��iL�.��2MgNj�g�9��*sCm����N6�5���1|*^�*P�B.N�����E���Rw
kR����u���XG�V]=[s�����-=�c�8�D�
�n�(u���V����\��?N��k�}�H�,�:�o���;u/=�*�S�;.�0�3x��jh��9-���HkK�����&W���^����<jb��!�j�
���,�8�<y�@��
WT�f�iU�u!���.+�8��UMr#���mMG�w�:���j���G4�F1�����S��T�Q��s���?.�|>~K��N"^+�
/(�1�������/�����������8|=yi�Q�����yZ�!�Mm~i��,�'KE���_�`�'T��xL>��X�5d2y����z1$�K''2���H��I
���M�V���E{����7���������e�Gb���]6��ws6� ��y�]B�C}2��������xx��m�a�?���g�r����@���O>/h�m.�dmj�����!\N�,m������?@?B{�m�'����XnC!.�7�Khg�|��T�[��{����}�&�'M��P{!�����!]����P�z��r�y	li���~6-$C��"�5k���S��������[����G$'>��
��=�S\l�n�s�K���,���r�=��b@#X�h�ODE�%�hP
�O�n	<g�A&J.A-!�/ok� b�
��.��F��a_v�Qy���Dt�c�j�5x�U��;�=e��7��J1�&��_������/	+b�b	E��\�OmE�'b���]G�..Wo���n�B�#���R�C��-��PxT>${�z�����R�Ww�Z�
�| o���J�Z�����8����@_m��_`�F�����Z~�����%����0�@�o�M4c�d�*!����ix�|�����6���oCU�[�3�[�f�|~a0��m�/2pm�7���L�����������m�G���;�M��F��.��Z�!zB��?�����zct�U{�-����4����t�����	
�K��H(}V8}�aZ>3:I��+�s���[���m����eM�L\Vc����%�����C���Hs��;X���R��r�>�6��ZE�_��21U@��T��e^�'F�g��l�gu?�������ig�`O�\�]�o��[����c����^G�w���s^_`L��T9�8������9�8��������b�&W��i��$.�{��8zM��c�v��m�K6$�����5Z��-V��w<;�G��,gi��r��+9R],P��,ha��50h�����3�@v
>�����Y��d$��^7t�����G�l��87U���z��*�Ya���j�hU��U��^m�����s�G������XN��w����8��;L��<��hr2NX
$D�1'y���a<����_|�7��*���8�s��
���s
�����0��s*W
H���BI�"AI�X�+B�.X_���f���yAwb������[�\��o��q�����/oKL\�3��:�2��[���WQ���IXe�[��Y[q*xL�l����G
����T��F����
��4I�O�<����u4|���_������dQV�3
�y#}�-��w3�G�������9s��z%����o�0Ocj3+O
�V���T�z����b	�j�{�"�������$�o�v6�L����V-��Xuj�Y/��q�6:�/���(�����Y-���,�;�F��8���XAE �x����$��8(>�jU��4?�U��&�W�i�E��P�{���~��.&&����n.TU(.
�,���������x�+p~U��\m�Z�^��'"9
Z�m���
`
v���b"��<����%6�c���#�x�.M�_.��=���2��k&��tT�yp�I:��1�e��e��i������K����b�0?�8��!�y��E@�k�2*a;����^���Q=����^��3��m�C/��b�(L�%1��Tt�Q���'2*�����yQ���?C~C�n)�����N�W��2\�����Kp�{�/k��uo�m����d"��d���	]?<D�@��-�������R���X8�Fsn�3����P��P
��kkkQ�f=/����]-�����X�A��>%A���}9S��Yr�d�[��@&�������na��Y$nn���WeF�uTT��^_��o�xW����|�~�Q��9Oz���K_3FO���Wx����j&k��n<
�lrz������[�C���'�|���!d����p���m�_��Qv	6E�������a�<�p�b��<�V]7'Sw2�%��E��c�#\��I���Su�7cQ�g���l4|�u���w�
���jk�Kjl�3�c���Y����s�����O����,[�{!���E�JC�3���\�m�����C��p���� }��o�?<��R�;��g��X���f@Vh��pd�=b&c�__�����p������/Ae�K`[(����������pt�����;{T�a���|/x�{u5�?���[���p&�2�����}�����5v��p�
`M��0�"�=c?�Lw�S�H7��?4Z1
Q�{^������~�����7�c�E�f��<�j�Ym������ 0T//�������Fc�����@
�:�����H�s��rc��L!�d���E��_p��c���w	���W�3i�t�����YR:�>nb�bG����y���3���,gh��C.�pyr�L��?+��w������~������Wsn�B��������U�q�wNO-�Z�M�Ub:?��q���'��X�
����:�V��:H�eL�����>�"^=����'=��i�k&��n�LiU�_x��(Qj��J�MOV�zP]�s�����"C��t���#���U���!������2a"c���ft�4^*��f�|�������5�&��0�Os9v�Y��Y��Y��Y��Y��Y��Y�?�r<�����,iA���a��=[�Z�_�fP��Yb>CX���(q�s������D��������Q�7��5;�;iS��#�
���p�������Y_��9�s�9|��9��k��9s��OB��96m�S�fv�VQye����;�	����+������M_G�U��_�q����So���\�k���^��������	����j(r9]��������Z�Y�3Qc�T����i�����1x�'��+�t�Ik�|�	Srw��!1����{���k��!���U�����{���P<�g(>���������mF#����7�s�`��J��~.����.����#��kt����)�)��~�o5�y����$<
�'�#b4b�����Y;SVPA�u��F�9'P�7��4�5���}�T�T�Q�Z���� i�y���/E�g���A���/F�@���H�Et���]T����\=���\P�/y�E	�E6,H��x����RT�"	�S�%��5C�BQ��4��H(��I)�ny�0~W���6d�9|QJ����
�s~���o8����h4�����Ftm�;Ha5���i�O��?8�K�����_<��Oy�1��!��S�,�Q����@T����9�����f#�F
�*,��n�6�I���iq������-�Et�������?����z��3�����7�������/G�w��1,8����!�U�d��1��5.i`���������k.�[/�	Z	�i��7���2�I�`��Z�?��Wu;[9�����Y���t����y)\��
������ei���~�*�,M������v�5�Fi���F?j��n
���ac�dJh��=��r;�d*�9�n� ����)���|�]��D����i���������o0�
e�TA�����`����):�A��4:�y#����b2Dk��[4���CYR�6�x�#��#3�}���@�s��e-���`���X���8�\
�l;1gNY0Z6:�����������
�//9'<~�@(}y���(=5*r,�g�[+��:s?0����Ks}�������}��r������w�{�����$L�tdf�����h|�n������������'�p�%����Y�Hx�C����}5�WNn���.7����0Ob�d�ci;��*��,�d��a7���`xv�������O�i����gO������'��_U�������������������
G��<.6�����x���:}j�����F��������'���\���C�^_��S�lq�����n������"���x�����8:y�K���4n�3B������y������0����\g���������\�������>�F����� &��D�z�3r����y�*�R�����6��B�2C#VQ�������\����W�?�r���y�A�F#�,"���������b��:�\xf<:�K��Ki7�P{T�;:���H����

�\��0+�$��������,�����<)0~?����y���y���E$s�^':9�#T���s���w����/D4�*��}BN����y�]��)s�}�����];}D��)��h�01C��,�����F%�1J
��������.��������-��b��R�v1�<"w�����6��7�����6����o6����),�=e���?{�|�����+��
�:bQa
���i�����6|c�wv��N�;�7��<.����T��O�T�Y_�LE���%W+r��������(>�mNh5'r�VJ���J[�%�C�n��,{�E���~x>���K���������_��:����8�&�����*��������	ct>��a���o@��X���g���O�vT��t��hN���d�7�	��hfD���1DlVf�f+��������������'kBh����o�akO��K5������IG��&���]�n���|W�DKh��}�jY��3X�g��x4�N*DZ__z|c������i��kn�'���0����Jd�>L�h��0�2�bM@��z)K+EdB;�,�,��Km�.�H�AZ�U���g���(��0����Kh,���k�J�{�?bZ�������T���6R�;YW�q�l�C��6�2����B���������7�u6������#�_x�w>�n��5^���`�����j����i��G/w��8���Nw�r���0�G�4A��?�?6�:�t�-+2w4��g���_�����c$���0���,�?���j�x����'X���z4`Sov=�]����7����;r����� ,�K����	;d9_Z�G���2jx��d��]�c��=�G)y���Zxy��-��������l��=��J�te�fhe��c��hG	U��j5���x3G���`��j7�^��Si�[>��!��\���z�.XAki��2K����-���2c�{��
6}�Qy�.�i��_+q�o�.�8�����7<��W5o���0��K�����������7�+a^���C�/�+�Qb���[�'��������j�l�LnN,��1Ce�����SW �*+�E%V�W7���t���������~�&F�h~�� �xhr=��'�3?@V���M[�s��tN{0�������:R�ti����_x=��3gK4����N>���������M�Y�_I�J��C�F���Gt�U4��7d7"��{�{�.I���^�O~����!�c�T��Z�������U��r�{|�>�Z��>��������P��{r��[nf-�dq�Oa}+��#D��i�����d����w
*�-s����r����n�����d��4o��3���0�4����|���
�/��O�����m���1=��������i|�a�X*G�Z�������ci���>|�O��>�?���O��e~h>�{�H]��������u�����f$�LM���Z�\��W^��&3�����D�����rP��K��9�&	���xN�1v)��1�4q5�	-��#�I����p%]{f�C& �q�k�h���K�9��)��G���(,_����7���|���0�)|��Z3�{���U�������3�{���&j��E�����|b��"4b���j�n� A+���~��b�A��	��-�c�}�~zu�i�~�v��t��{�{�N;'���"r�r���I@s��������,���;o,����u�<V�s����~Dn&�t*�%��n8���
@@�y���w\+�IP|�gpv����U=��A����8�:g�pd��<r������8qF�s�b�=>B������ab1�lB����&HH�~>	/�M�6��S��A�W��D� ��M����B2����=@/��]{�u>&�\����U������c@�	����V�@�l��Gs��E�������3����C�%��m4<���^`$m�k���e
���M�[Y�H�OH��29� �XG��#�h�����75��N������.�������!��d��}�w|��{p���F��^�Vb���i&o�k2�dQ��U�^��j#��������{P�m,��#����������7��E�t��v��s�9on7{�Ki_�|:\��=-���-�m��cB�c�{`RiVZ��
e	�:��_c�(`���0����>�;�j��W��?Kr�k�z�_}<����`��aRt�����~q��-5�a�|��O�����c�V��)���	�u,`;���!���!!H	�!�i��:���)���)! 	��Ci�PZ:���" �Plh���n�D<�z��t@���U0u����q[]��e���.(R6c��w'���Y�\���-��X.�/�S�;��3���d9f������7�t���[x��@E��7ww�]k�b���j�=e��4O���t�NU
�3G��.T
�/�3��]�b�B]c0���x���b1B���f@��	��m��?�!�nN���.����*�8X�j�A�D�*����#G ����s`?�47S�U�T2{�|��#�'�w�p9	����������~Y=������\
?*K*�$�%���$��7BG��X�,���0�����E�J�����������}���i]���N��F9i�������~�5��{9��&*T��8���C�����^Gy�����~�����T���z�,����%������M9K��{�������w	��
	L����CT�`�"6D��N�F���>���vNv�;��������������)���+6����
�6E��+5CVf���}�
E�v3PXq5���[������f����3E�~���W���aig^���3^$�V�8�u%���7�v�}%�q&��d
v��a'b����CN$��&0����>��a���<V�������6d?�����v�V\�h�b��?�!�.(�c1��\����	�K ht�S�~�������d^d�
�������gb�[��84r�0#��6���/ZN��yb��0���1b�*�&c�7T�iX��l�'W��	���p|�$��&R����G����@Fb�9�S��)V�0K�����K�"�g���a	�����L�2���p\t������a��.������dz������nM����/?�O��w�����l�U[���:��}tT4�qf����"�&�/�/�I^�I4�4/��.;������u*k
��:K��`�[�X�������G�Ew���pSo4�������t��1���5��>�|���;������D
��w��^=���m��O�'�����
]t�+�K9������1=�"���_`7�	/��$5��eh��/������1���0���I���#�C����g���~��u��[u;d�������H��%���`kf�����m>h���vls��?h�Z���������$3���}<W����Q^o��������'H\YZ������26�`���fzZ���$���:/��8 ��1�I���L�0+�k�J�m^�����{|T���1�CO�)'�1����%��?ov����1>��;e,U`�� �!^���t���u3�5����zccc�V��
o�/3�rj�l?S>�P�H��Qq�Y����7���0��$��[[�;\��(�#�Um5��IX�����}����e�qu�U�B�>b�-�I#/&������f2&g8�����&+��`\���trI�h���"@�q����y�����u����k��%;��7OE�D(R���d!8D��F�ir������Nv�r����w��BT��qL�wpN���}0@,8�� ��|l��97��2����FNn����Y|���Xv��X����{�����8����1'���}sq���a����q1�?	�k=��^��0�e���2�`�pl�,�Q0;j�-g@b�=h����*������.Ea�[�:"��(��i���K��v��\B���s�Z@�-�C�����zx�4h���O ��8�8L��g!I�o.�w1 ���V ��h/��+\u��8C�����v��n������^:�B�`N:�BY6�a�5']����FA,�iH�������2����>�P]����6�H�6�4X��B!���4��i�L��KR$c�Y`���Pr��L�;R�p���hU6�YY����R��]^]T�BUs���+e<4U�JDYi�):o�b��J�l$�,����Z�D�vX�9��t�hxy����6�X$���I�g�M�:KK�g����j��i�����b��"H�@�DA������K�v�>��2:�K[Q�9a9/o
�'#�dB9���,�F:�Y���c���./���X�r�l�oU��<�]o6}L^��;0���W�?������G�|*b�h��7��u2�zu������d8GJ�Kwz~}��g����I�J��z�We��#�H9y��.&�5����/���s����v�z(���a�-k��"���:h)���2Q���#R���p.�	��1�N;�������V��}���fc�-�N8Uet��K��w���{�A��]��%��;ug���P�[r1E��~h�bZ"w�$��RQ�t?���k���cy��^�
N�ZoVug� �����zyY��?\�����O��U��j�U��#0��&�uB\����r�(VX�avn��E�����6�r,����K����s��g�mt-	+�H�9q���#����r?4���k���0�*�������c2��X�����'�\v�u���N�?/m���*�O���P�*�8�;��t���$BFT ��5e'w�o,�mX�"m`����Z�������i0�F?��^8b�R�GV?Mn}��L �����D0A>�eG�daZ#�OQV��P]�sH����B�������'����5��b"��{�R�2orw?�������%�M��1,<yrrh�[J�Ic.��?��?��?��?��?��?��?����8(�k���
����7�%4~�����
��L���N���iO��x�r3E?��.#����A��fgGv'm�~���|�4�q�Y
|B;��r2���1���<ZsR$���7?i���\��N%���ZE���'�W�t�'�-?*�������6��W}~)�����N��Sor��e��3�b�i>�k��5	���_p
�=d\&�����5<L5�S������;�0������:��XPH���H�K�����{���Zw�GH���B�������`,��3��X|���cu�6��GLY5N���X!���~���n+��g�ax�H��'�hi�d�(��o�b���Q�$	��	��3'*n�u4e%�_��o��s
���9M�w�X�����L�OsP�5�e_m���V��[��R�~����(S�j���_��Y��Uf��k��^����d[l�X!�R��" ��F<a�(�)�f�����5C�t�
����_�P�SSP���a����um�s���;"��;�L��p8��3��p(q���
�w��j�:X'R�-��4�!��q@��#(US�x$iR�rYi�N��C4��PYF���H=��BE'���1]��F��$2�5Z��2m���`��'�g��)#��������M&��s���>�g��C���pmg�A�_�.��cu���C[����/Ibu]��Z�U-o����l0�4^2���:�	�o.{�e�����j#�V#~`#��v�rb�-e��\1��D9$�a�3�����E��������w����X�
p�b��)�����-7�QK�uk�Hf���Jl��a��s��d*�Y�ne!`���*�����^��6��0�������{����2�{EF�������q����3���p�!'���|�����k�����l8���d�qF�o�Z����w�������fo���{2�n�@��G�r9g[��^��������[�Bp�n�������� ���x���`g���S��w;�g~�k�[�8��1�5�YH�~������I����p��{���x;�C[@T���	t��5z^s��<�S���W�lvtH_t�[��K���M������5��h��i�w>�2
�r�%#/(�v�����������(�_�����t�T�E��.'9��;�j��"�������s������Yz8������wOOap��)�����������=~�@W����H��������HD����I��x�3o�'���LF��\�-�?�����q3�Z��\�H�����Wm�U|������l I+#x	����@1�g���O��Tf�t��h^���m�mdk�i43"�K�"8+�F��\?�������I��'O�HSg�3�e�|�
[{��a����<��@XX�N�w�S��9l7?\yI-��W-�x�b,�q�5T��
�����W�26��_1���%���; b�}��J��j>22��#�I��<�C��f�Q4/�/�D�/���4�U^&4����"����&����������^�v�����o
�������2�a���$��$��%�@�9�~�~��������;R�;����t=D�U	Ro���6�U���������[�zx��*��\8z�w>�ex�k<C��`��F`l��c����i��G/w��������]�ptA�����Q�>MR
�aA����?#{����3�}��h���3qh�lL�)������E��m�$����-�0�M0�gb�^�l������������R~��S��p��euI���]�������������M���jva��s�Y�m�*$�5����[��s�7������3s��H3��L0OCJ���<X������9Z�kC,9W�7���J#8����3���t=G��;]`��e+�,I�Nl;��|s����g��s8���G��[pB�P��Vb
��2��-�P�@H����=��@,��%��Q����K��������������
k��-t����>�,��?�6�*������O�+>�������WY��#����T�������F5~��s !w9�K�����6q<`���BY����:�U����M����v������Jym�]M���^���c�:s�D�,;>���������A��q���E;��;�K�e�Z`��'�h�So���2P��w���}���?�j���-#�C�I�?V���/���^u�/'������bl����~g��p� S�W�z������2�3K�����v
K�1tk���4jM���2��_��7�/������n��[-��w6���?N-<��9���=�3��c�������i���M<���Z3����5<���>����[����4>�0x,m������������c��I�����q�yCQ.���?|}�6����+�����A������`�z������JN��V����U�AF@I�.x=�2H!I:��MAM���	~"�?�%���B�
k���YF�����'�{�mr�1h5�#�TE�h�O5���+�YT���������<����B�����}���^��8���e{(e=M����J����Y>1�j1O���Z�m�(H�����6&�?c+��v�������>}���s��{�{�N;'���p�r����I;s����s!��8�a�>*?owv�x����7f����Ge�gt��v��y���

�sv��4CG��t������]����Dxs������l��]�7C�ea����������5*pBu�k���qJu���(���y�l�	M���eA������(>*��a��V��%�����JH�~FT�1{(�X�3H!��E�[�H�������(��J�����=@/#��Mw���C����7�G����q/9hn����=���o�dn�u~�����o��>����q�43]".j��\x�2�:�����0S�����B�/s����� c�<���q���WW���d����f,�M�{���>�TL�;��2u.��<V�VX#���kF�����C���}�d�X�����K��b����Z[�x<^�?vo��/j��
�z��4��z��>X��H_������$8����v���t��'De�=��Im���8z���-�i
P�4+��z�N���GL�RW�����P�tb�-�uux�;�w6MO�FC����*1t���������1�4o���o��m��A�����v|���������c�Vx�)���	�u,`;���!���!!H	�!�i��:���)���)! 	��Ci�PZ:���" �Plh���f�.�z��t@�����54u����q;����]P�*l�+H���.�K��<r����0����
����R��6�X
g�	�0�vdH���>������wo�Y������UX8*W���NG����>a���'��.�C���W�"��&��������zqW�X�;�Lzv={��X���#�P!r��~�.���@J���h������J5�����4�c:��z�!�H���:�f�;0!4�7S�U��2�����#���w)4p9�P��'���^R=�������\
?*K:�H�%��#�m7B���X�,�#���[E�E����]���� ������*�!0����U0�<Q����q����?��}�Lc,h��*��_�O�M�zsWu�u��z������^jR]���]��@�[�$K�'c6�l=.�wv�;h3���%F�
1��p	���:D�64b�$�����1����i�dw��co����������Oio��fC��h�PXZL��vse��l]\}����Z?`�@��u�vho����R4�a4�;}��)p�^e�����xg&f�x�������
�{�f�����:�0�a���H��a�v����V]����AW�,�q{#���{�a�f����0�,�p��U�?���Ov�%	B�q6L�<�X�s ��@���l�z�\��?���L��O�+/<���5�����;�id�W�<��q��Hd�j����ml��q��:ti�C<Y����I��

U!^r�(��Y8T�������=8m�JD�i"d���!ql
�(�
�"I��X�L�lr(��6���+1IV�f1\��!�J�?�2	�_r�q�����(�2��e�t�F6B>@g��%J����_�5QJ����>ik����;����V�=��j�%�G�t0�Ze���>��W�)
Wb'uguIM�"L��&vQ���Ffnd�f��Z���)-�������_�Lt'���y���u�P��z�1WQSo4�������t��1�}�5�:f�����w�����1�4�>�Y���������?<m�t����vZtO��s|����{��.�| I��/~��'���� �$o�n�y#�p�#�R@s����[�
���X�Z��8��Fzg�z����g���o�����#c�v�$[`�4������o�r����}[����%�[��;��<p�p���'����������]����3-��8���<M�z�j��,����|���E��'���6�M&A����y�\����9�H�f�v�G[�V����QW�+��{q����+Pb����sO\b�v=�������a�{����r��SV�R69	�U��
}�U�����Q���eA1�h�w�dP�P!48������i�K�}�ZUb��:�zNH����I����c����l�����Z�;�3��x���4-��@�\��������,�?\X���w�����)�-U�1v����Rl�x��s���6h����G���>��r�+�-�g�2��r7E��1x���OJp�VM�2����>;���7��8d�5���l��B���(Es(+KE���=2�pX��{ �2���EF=�?����������������f��{�0��k8�
V��6Z���/)x��CyHC��#&	�T�����P�r �C����1m52�GT+2\P����Hv�5�0��E�i ��[[�u�|7*�:I�����SM���
���B��$Gx�W���"�<=�J���	�c�.:�W)���h�z����.�b���z�����K��������?�VG����&���T
.��s�c(0�\9�K45$[�M��a��jtd�F�	�z��F.Ba@.B�j�i���4��eY�c1����HZo����4i�R�_`\���������z�F�3�j
&*��j
'tx��\�!���8,��|��HC!2��%t�����OR��0�� �\,�)j\��!r�t:�_-C��F����D�p����\��}O���!D��\v��a�w���F5+N]_�WW�����\sUn������������i���2����d�
���M��N�{����k���
��_a���/��ol��X���%??��K��?�06�v�.�u|~�����������jlU�-C����>���X��a�Y]��V�K-�z���`�]��u�|�'_����
l��hs	)u.Y���iW����z>�+��~���T����6+o�oT�M}����n��1��4���t qB�m��'d��43�Y�lF$���H�pS�h�����V@�Z���aF���j����p�!�r`��f�__�:��z�������v�f='�A��8����
�X�qp��&���kv��o����������op|��]M'�����i�
M���_}�����t&��9�V#�]3x�p(�;gK��p�j��7|���6,e���k������!xm85���� ���������:�����A�F��Q�be�wSh��������'��q^} �Wo8v����7����x�l65�5��J��	�
�����7��4��&H��\��c}4���������z
��
����d�����vr}~�G���{'�jS��Y�`'�y:��t��VzAf�D+�1���H�`������u2��>��n�����J\�I�SZ�Gpp{6y`���l"�E2u.���;���z2�n��[C�D�[��Q�����l�`Nq����:�O�����n� q�B���ai�{��q6c{,
�=clW8�;zo^u^l�g�"���	�o��@	$�0�R��D&s;�����!g��������?��?��z���p��|<���rF�wdp��|��@P$ySV���d���������l���__]M���ed�����N09!(4u���0^�������	��7;��J��BlRpj"I�����w�F����)�����!��1*��x�l��89��x��HhS������.�cYf��M��e9|�4L.\�����3�5�K�w�i��3dRL���xO����j�
���'�$d���8^�����g5bq��,�>d�����wn���6�Bn��np��>�x�}�eP���T�Nd�w
�*fQS.��z������� �j����o��@�����(4'�{
pI �xk%||"-��cG���H�Q�3���2�A#���p�d�LX8�E#}�X9���vP@����R�R�4vF�\]�p�@F���O��1n���@��
�O.�&�p�U����f��?i����uW���G�d�U�k��M��X��W����@��Gv�(��@��eV��y�h�Z��n���'KhsqK�,��6K8�qz,P��T���Y�tO)��.�����+!KN:�3Rz)d~$#|I�E�3���6(��)��
�>Y�F`����������&�M���w�v�/��h���!���i��q'>C��	��Kg��������:������zt8_��3'�8�T�'I�3��o
�7��dZ���d�l�������(�,�Jd���}��y&H���X�����z���9��e�0~p*�-[D��1���L��4S���&�H�����%���M��������;�3O�0zQr0.!����w��z�6B�]����y�����3@4;v
�����EG���,��F�!���~.����,
A���-��:h�m,�N��{~��'$>�B��s>B4W�QK=XGUj5'm��n�����gS�]G�)b)���4|$/*RQH�<I^B�q�r�������t����i1Z�����������}�o�����{����{��A����V���c������N��6���c�C�|�-t�����Z:*d] s�h�"Vr2)�!��������5Vi�\|������\�8��"����B9@��=���8%V�Rm��<�,��2;c��PS���v/o��]����eh�ZX���]1���=<Q����%���7���#��F��E���S�:1S�#"��M�#{��M��d{o
oAV���&J�$%G����T�������8S���F3��JF�!���W��*���p6���R	��t6����9�VnC��B�����nU�E�]�����W�1�(�|J�2P�5��o��������^^�n�=7	8��$�d������l�@wO/��8������.l�{�j���eI�S�.<���|4���,i�jjyi�k���]��$���%�!Ox�^�*�Z��lOL�OR����mk��p+�Xr}m;�-v1��j��,�(��fS������H����^����A�s�+ �����ca��&��I2���D��?���5��~��u{���@z��!�X�;`�Ls�3��\���>~&�j��<�/#���z!{LH�f���D|���=�>�1n]1�Q:|<1w4I���o�?+��� \��!"�'��'�U'FQ������������D��#�T�J�r���_�U����y����&Y�VvX��;��g�>�G���3�Z���wT����u�1��y��)��y�E�K
��C���0���U5�MG�4�25�4��!�D�����k��v�I
JC/�_��� �<��g>g��S#�cS.*8�Y�����1SWrOAd�^���ecW��������������(��z�rOt�P�b ���A��b���c|����R��b��h2��
�'r�M���p�Z��G��#\{��D&���k_���,�0�TJ����w}������rO�U���%��[�K��2�~#���&�a�C,�����'!�)3�������tg������U�Y��������b�v�����Q�QL*����-;/�������������x������p��w�!,���nRL2!g��TY�Hu��o��2�O��YD���y�e�d�CU_4</^X���SO^��q��S��g�s��LI@������(vn�����s��7���m#�i��*��Ip�}D&�[����L�v��HT���GLl;��R���s�Y
y��I���?�d:�������6iv��K�0��vt�eO8�5N��9�f�}V�����,��fNQ"�MiJd�9CC��L93��&�����A�7�����Z������&���,��$���m�7E
�������)���	�|��V&Zu����I�YN�,�'��G��sq�nN������%c.��DW��]��TuO�N{�m�5���.����e��(����	�c�	�Qx�#�;�������[RD�w1��~d���os�b�%o/�O�.���w�����{at1Y����#}�B��KIja��H�I�hc��~���]�=����b�J
�]�1�H,������Is~1�&�V
�=��kF��b�8<�&�WcQ;���Q2v�������6�Bfme�K���@�\��2��+$�a��Vlo	���I�+�i�,#DbR3kQIR�A���2
(�ay=��$5n���].�-�l�Pj�d�N��,9�
�
�o�o��+�[��i*v:D�%E��.��]g�WrR?�*�-?z�8�b|q1%�K�8�����_&���T�h,,���,�zL&}���t4�[0g���X��������
����}<���6���������6h�%��?�/:)cj�kxE�"�[�rHPpGAbYc��kx�cr�n���=.d�/�/��G2�V�~�3�\��x���b�j�@Mki��k�H�3�Y����y��f&���*��[n�|R&[�e���������7��4Ys~3�z�s+������Z����P���Rv���,mg]$w����S��NeF�M7����2?%���eR���W�J�i�{.�����'�Zz�A��E���P{���\+��T[�
[������G�
���Gq��@(��S�������),n!����@��J�\`�++1��
ue�O;��������$9�x��&��
tj��-��i8�6���4����[*���o����|��G���H+�^�V������>#q^�W��M�.!�o�i��B���R%P���s���k(�z�F��,4#�w��[W���"d(
��M�!9&,>������q5=�|�rA<��qtL
��G������wQLw�D��`a���x�_g�p�2���yP���	=���������~$��U�g���+D�@f' R�L/����#��A�}t}����]G�D�f�A�����c��H��?"���K�]����
�w��&���T@A�����(���2������z�����=��^��I�d���~�b��s�x��hqZ����>��}N���Q��K� rMuA.Y�?�������������
=V=(<������>z����$�Z(�����X8[��(���D�\/�BE?������Ze[AnX�h��7�W.J���(B�x��|����(bIh*�Z�3p���(�IV+zG�fEQ����Y�@ck�w�}q�Q�[�5������;��E�s:D|5Ld��jt�2���D���;�Z�R�y�*Q��G�(w��J�;�1G�;�}}�cj�����w���w��}T�vQ\`3�)�����b�w��|qQ���(w~�J�;?E���S
�)wnJ�I����(�	���'��<�[�?n���u_��=�[�+n����.*�Bd%����$}4���A���������G��oV��Yd�1����)�=�q��;�`zU�/|����M4&���b�TH;9�C�Ob�O�u��{9�e;����;UlN���*��}{,5Xo�76���=��Wr��9��V��[ldM`�J�F��_*�����l6Q�n�FG���������P5�%�b6��ig���<���sN+[]�m�P������Z�C�.x���1���d�d�y�qe4>9A���x����|xF����<������N����pt1	���he<���d��x]���6N:�E���w�+�Z�����f���'����h�����GQ8��D�����������tz�'�"�C7b���+tz1D���,8��Gh8;�V��CB��6���{�w:�]���	����#D���y8�E2jJ�-*{�1)�x53�����E����?_Y[�8�>�E�&1��x3�w+��Rr�
70[�D�lm�a0���������Q��� K������;�?���
�(fE�I�7I�I�B�g�[E�-t^"���Pb���$��-�`2>/�����!���3��~6�����o�
�hx�� ��e;����}�W\2���d:(�N�F���/f�������WW����G�U�1zs��n<Xw���t���^Wz\���ugE��9���t����m�{u���u��}�k��W{�����F��{�F��A��3��?�E�������6�^u{8����������E�w�� �U
�}�^m��}m(c[���H�%���^���>�]�}�z��9�������yK�I9�|������������`~�n�_Lq�=���Ha=��.)�\����(����Y�������������Sh�s��w��B����+��}�s�P*���76x�<V�+�vE�=���u�p[b
�$	�Hh�9�Mv���>C�x�$&����c|�q�������FO����zo�����x�,Xk��g���	u~���L
}�pe����1���f�����p�_�������l����(�x���o���@����;e��B���F�>�������O~F�{��^��v��Y�h
�H��X.��]U�*�U�^E-�cL�aIuZ����z<��SHk�f,D���d�aLLd=\=���,�z��\�Y�c�k�-�
B����Z�Ip	$��g%E�J*mz�"9�eO�������y��y�a.��o�M�A�@P:��q�N����3j<i���c������,���@�^���z�D$���I�	��'��#8������~������xf�\~lV��G���G������n�M���R!�Us-=�������������e����x5���k�M���r$��,3qv��&�����y���@����W�,�cF�w��k�sY=�$��-@�*$����q�Jd�-[%�aP�>*��q8����`cu�{��<@������&��-�^���y-�wd�����%}dz��j��N�ha�RJ����q��p�lj=-����Jr]�l�(���Tlr�tL/������\������H��d>;���.m����8������jV���U
v��
�m��>�6�Z=���P����sp3�u��x=fn�G7��N��e[L���bJK&-�����e"1�j	���$�.6��J-*��JVudY�e
t!���������<*��I�o���.�Tg#3�y��\��$Y8�*�O�uiN�q�"J#x�9�N�/��t����an��=Fn���T��U���a%2U�����K��L��J�A��e`���@�,_��t��>*P^��}��6Q��[�Y.�rT�["HY���a��-��j��j�
J*]� SE>%x�d����N�)}]6��|��
0.YS�Bp[�r@����A\�#ar�T>b�5�Z�
:�Ie�d��lQ�j2�i��3��&�*�@Zz�����h����
Mf��!O~e��K]���iA �y�f^tL�0��7��������P��e�����wM��30��",H�����9�IE�?���kp1��X��F�+g�+��������.��&���H�Yo�f��2�u";���P�:V�e����.�u��}�-������E]�R���n�<�K^��1O�ZM��U?I{�o%��a���4�j~�
�1�`���5��<G������k����:�'dMZ�r�d� Z�%�b!���"���������x60�Le��)q�G��mZ{B�-����;6�-B�jYa��
lq]�=a�������p1�p>����Otn���v�>��,�����GI��{���%Y��K�jt�z��{��=:��s�y9������Vs���I�0S�7��t����FA?���a�4�5	N.���|jKP��X����yp~��f'hvgsl��g�{��)�������:���V��������,��qP7�m�UJ8W����d�}��$�X�Rn^.�i4�M�h0�M�`����r��P7}j���g�
#���|���9��Y{��� P<�����rh�&����e���S��Y�&nG���6�_R����{\;�h�
������'��9t��w�Dl)���J�K��l�������2|���9��r�{l)�����Sk_����� �m0=���$��{~�y
��D����'�D��5�� j4��r-�,����=md�����d6�c��n�����
7zGT������9���"t�V6�a%�K0����0�C�f�y�qmr���O�Q4���;�_g���Uwy��H$^�)�`H;�X#-��V��uP����&bRf�����@��	���X:?����b����L��-��&O�aC�X�lj���v]�P�J&S3���W;���!|�}9��kK����}L�xK���y���I�����`��2hO�V�!�h�������;�k@_+�A!�i0-D���OO
��4�e���&�c�]�:�$���`B�9���\I���E0���?����2�2���Et��2�#�S!zZd��A�F��[O�2�l)$�z�|��S��_>��D��&e��eJC��������r5��2��R�'h2�������/�Wsuz��#�%@h�j�d�����6�!�`��}-�D�<z�`�)����W�:���'�W�3���j��=����<pn�YI���ChT��n���|�{P�����uv���5����P�9�v 6�v�UYF,(�!���I��FP��W�%����^�w
�������?��W�	z����9���/��5T������4D�5�5[�m����E�xQXP�MA�n������hk
&f+
j�0��X�Hb���t�+*5V�v{w���v�����v����b�0�o��/����a��eD:���z��h�S�4*�2 ���(������k���,���P��m�w�[-�p��y0GpJ�&�����bu�=�����
���_�^���n�]���\�O����"��C���N������e{����i�Ql��j��������F��t��'��.�}?�X��|W�X��|W�(RYH7Cz�n�JN3�=�z]z�e���&�N�^�u���Z{1nM�Z���j<���>�[���y��&����pyc�F3\������t�d/�*�h�9�s���x���[��4����U@Q-YV ���h���<����2��I����t��>��t
�>�R���!Rf�
���]�MY�{k�����tS�%�|6�[<,C�n>��".��D{������~�Vy����ZU�������;����^���Q�YS����s�|�*3�\uIz��q��m$)[&���;�lK�T�ET�h�*���1�S�
79w���V�N�_��1����
�I|N/XdT�n�T�5����V���x������9��@����'�X��K�
;ny�DMe�D�:�UO��l<�s"I��������O��o�_u�oO��,�V���<ZTd2z,K���4�X�&cT�3����l2��)U��lX����Yi�Y���O�����G���E(��'����]E� �e�n|����:������q���-�"D��x>��������s������}A�������/����W��9�X�2m��/�8W�0(�B
�0��8KL����m��`����A[{{�{�^l��/��f�����w����F%�0m!�^��A�N8��R��z�����������������5�x=���&��n&s��b�?�PI�w�������D���<2r�@���V��H^t�b�b-s|L�~	���%��sK�E�5�g� Ys���|��0�j�������
���}tYB5��<`��]	�.v��W7��'`u�i�uW#���cN��=�}�o�/�l�EO��M�"%�s[������D����Ju�&"uG���������B����o��|���kl����Xy�&���l�T(�
���;>5���P	�P��;���Ib����nAF0ZH��*��D������/E9��S|��9�mM�
<�yo"���,�]h	N�^����`�y��R�k�>�7z���~	FxW�kP�-�)�L��;�yW+�w#g���Y��ii�o�=��C�4�(i��t��o���"����� �����������b�=
8x~4;�l���������-�|����b��X����A}�#��= ��v����t*Hc�f�a�D�E�A�c���*�f�FFXNS���d2D�?#k����yn��GfEW��z}���<�%���b����d9,�;
�Y�X�`�j�9~�y�@�J�q��]6k�&���Y�0�����%�W��Ps���gS��i�9������$%<������S��ZB��]�����}��O�)|@�#���Q�u���K�1O��v>}�Q��FM2�X
��@����To,.<��z����.���Q��V���C�x�A$�K�ZDVY+�-��	��N�����V�� =g�?o����jk����prI������9@��m�~��g�����<�>����|Y�����������0F�+n!�4��9a'�D|���������z�������5����t =�FO�R��fXJ�5�@X	PoB��.��y8��e]d���3�q[RIY�1$�����rN�/�%�5�5�1xI	'�zH��&e��D�%��[b(�}|Ex�����iA�0f_��QcDB����	���B���������l�W�������{h�`S,���j���eE��n����+�����DH��������l�����2~��������}8���UHt��>��C�eE��8 �Pr����k�JnEcX!���D?��p�#[p��/�%@����_��%���iA^:H���R�ci�������1�q�����uUi���c��8;�/� ���p�q�V��B���[�-����0q��'���~b��)�(/-+�@:��lr�6 �<
�Vh_����>�:l���R��/5G����B2ME�	:]��P��MS��D?JVm<"�6� =m� +7���#�w��8��q�0M[u�����_]q�k+Y02����~��7���t<=�?��}���� ~#�7-]���Tt��mx���#��+ `�BxJY�
��6�,��������ndT��b��1 ��.�7�����G��9X4��VdN�h�hd����P$����G��_��A<�st�iD�m[HP/�������c���(DK����6�`y�������Y��/��Y�h���Rn�V&�)�{S�����-~��8_0X���j`UnYL��9�*�8W76�J�;�M�����lQ������[������<�]%
,���(����y�`��`~����mn�(���y����_L�m�S�#���L��A�[n�:�h
����~P(�+�	aQ|Q�}�B��,
�IO������&t���g4n���B7�@�1I�0]Y��sZ$Z������A?1>l.����WN:��)=��Cc%�z����n�6w��'�J����"
�����d6?`��q���mF%"������P����Y�^n�����D�Q������pq�f�h0�f���d<j����|� �{����z�?OqF��$�����w�pQ�j�<�V�&���
+����9��,8����	�S9�K����+k��v_��^E�>�M[�"�
����tg�Z��w����z���W���@X��]�z�UQ�93>\z*5����,Pr�6��@��>i���K�4�v��)�������q2h������1�P;��S��Y'Q��:�s6���[����3��t}�C�b���+�x���'�T�/��T$��!���'�Z��/����"<�8�O��0�E�H�.�=�����k^S��:]��&���N��3��>A��(��~��<%��s�������[:`���.�tz��M�����'�z	^��!�,������ }�
��T��{{�����	��Q58^E8�mV$�M��%��"����*U��2�j�n��0Iy����5m{:YL+�!��X����e�`����%^&�� |[~����^�n_Z����PT�zY�EZ�t�U+�Y+��3X>z����e�XSE)o	��S��`]>���Kq�-zI��&�k/i��Hup��9+�;�.B-T�����)P�lK�A��C���u.�Z�Ic'�3��u���,����.$Cu(�n_�������LL �Ec���n�UVEy�<5��8���i������@��O�����.����r W��QntN�����m�Ia}M2�����a{�TMO���*��Oy���J�<�L\qNc�*��;A�4'���5v0h`
�V�g��q�,`Z�������� ,
�oD����p����R�,kE��J��5��j�a��K=����k.������D��V$c��J#c�Y,VS��#�����#W�Q����V�S�Dk���5<��'���1Z���w��[��'�"���t���:f�?�������Jw{�!�
j����\��%GP��i'���$bx<O�KJ��^
�L�ST����V�� N��fh�cC�@��$>V���+F�(-F/��e�g����S�����X��,����3��8�5��@�s!*YU�}�O�uv��x5��s
�1�����
�����!�>K	f�%�W�?5v���
�����c��)@�������N�4Q�������	� �������\7��+R�ITg3�h-%
���[7�]�K�_u����	���E^EU��d1T�b���,[����~W��j�w_���e���l�n���9��5*,��8W'�
�J�����+��.��;�e�e����l��w�[-r4�.0s*-9Td6�"�s7�`���w����mYW����}��"�#��
@
�_u
3UrTD��>���Nb�����
��������]�����]��H}!�
���;��+�'\�K����=����E-�
"��z�[Y������Z�o*���^�%�^.�I���r��=�9^�����Xu�p/�*�t�Y��(E����������bx���j��	R�wE����R�)�P�J+%��|zY�}�zY�}�z)P�����qVj&�}�]&�My�;m�����uSW��%�~6n\<FC��>��B���D}������~�X{����Z��W���+��;
��������Q�ZS����s�|�.3�\uQz�����m$O)[(�#�;�lN�t�et�h��P��A���M�:w�����N�_��1��C�K�R�2A�s�y1�G������B��%�O��qh�)��b������
�+��Ot2���l6
���Y������������G����o)�dX1�J�:0W�t�z�$	�I�)�l���!f=%}@����s<�(gT���R����������(���C'
���"���L�]�:'\�&�����d�td������Q���xn37���KG���j46t�eS��An��������"_qNu�k��*#���
D���8��]��'��n2/N�4jarL�`6����!��m���|#�	�6u/!��L�cWG
�oZ�������,�"=��jFO���_X�9����@��$���;���<���U�S��(��������X,ZZND�4L�.�mM�ML5��e��g!n���B`�B����t���r��Y��0#e9�2���$[&��%_�+`�z!�w��V&�F�2:�5���#�x�g	�i�T�r�����o��D"��e��*$z��J"�D�o�	'��5G�z��js{�G��B~�PKhg����*�le��
�!���������e��6���4J�"&��^30'*�����,������a�W�Q��p�
F���v����Q	s�/��T��e�d�4fg��5��*Y:�]�b�8��]����6e!9L8�����-�W�#��<�-�n��2�V3��m�$%<���<1zm�8�/$���)���D��C%!���4RG
��M2���_.�"h��o��j��m^Mu����\���/���J0�	��h�I��T�M�>�N��|Lb���9����T�%��ovD�M���/MW���-CJ������7d*��Pg���T$=I�����?N7g���5���D'�NOje���@>
@��.��y8��2*gJ�0�9^��M���`bq9�2�Xx1-�����K�*)�CG,)E\��-�����"���}u��g�?JI��A��Qcr��B��l�����,vj���?�|�����0EYL!�k��J��5:\b�Y�J��$7�4��� ||��(�A/�h?C���O����>���d��(��@��!���s���������
`\!���DG��p�#kt��.�)A��	#����.=���R�h.�,��.��
�kDFg�lAd=,�%��.f�.�Q��j�dsF�V�ys��lbZ"3�l��d������|�����	[�NN�//�]�������7��G����(����;��
���t%���$=���:=�����<���%��/�@����)����F�/�;UC|��8Z�&}�MD&�����C%�h����|D?�����|:���E���J�`b�������~8X�D��b����?��\��u`A#�c�d*������"��n�tmM���2|�����
�(*���k�K��#�G,�`��J�a�h4�r~�b,��XD��d%~N�bQ<�st�iR"4��� �dH9d��uGia��?�gd8y�#P�%"?
���*k_��L��S�h�l�R�VF�)�c�����.~f��;_V��l`Vn>6�l�����q�nl���w8�F�96�E�y����������2�njI��/�����ur�3An���:�B�{��;��=�������W���>�G,8}���/�t��/c��z�k����>��@��������@A�M1:�|RZ�B�]fT���g4n���B7�@�1��8]Y^X�8�����A?%3\:K�'I�R�������jx����HA
��Hc�BOO�j'�ER7��l~�����?��JD�����-�NO�����u�����.z�������?6��`�]�`4'�Q�v'� X,������k�H����yx��E$�������KbWW���/67\S=PZ��!�9)�����IN��J�>X&]7f^Y{������*���l�"n���G�{��]���'�����'g��
��������MH�k��K����x�1�z�nZ'���@���'�.�<��I8U�Tu���Y	��"�}R,��X�	��k����;=�_���\��AHL,k�SY�Pt1�69������������R��l��}�"�Ltq���t�_Y�����7)e�SU�'�;�>�%R�����#���}O�F<x��w�y���(��d�R�����Du!�V��k�����.	V���|�������O�W|� �C�}�D	��������h��ZM�"�V���V�+*�m�HPC��?��������*�m��~���f7���G�ZQ����FB[e�)�Qi*K�U��F�/��X�)��S� S&�X���y���hI<46	���y�j>���N���M�-�}|W{������w�=��n������\���G~�_��uM��A�8ui�kc)�_s����k0�,������4cS'�i�i^��Rx�C)<x����Wz~����������`�N&�����d<=�W� ��}�H7����N�Bd�<���]������Z�Reao~��
d=O-e����<�g��E{�nZ�q`��`����krA&��j\W��M��u�`0��0]�������8
������IS1������v{ccx2|0�pq$��#QB�=|����?��������d:#���6�n�<_A�l����
!��p���}>��S2�{�9�|1O=���M���J��AN#�0Y<	_�D�h��?�$t����|~��C:��N.��f����u�a�p:�8}�Nfs<2���dD�`W]��db�H&:�Lt!k�2��eB#j��D�TD����,�Z�<9����	�-�!�Y
N�����������0Q�A�m�zaqB��'���>�?Aw�	��,�eGHp��G�c�L�����]s�U!\��%Qa��'��g�������`���c�����A.�r=���P�
e����/	�������#������mb��w
����<�R��f�l�J�M'_UI`'�n��������R����)h5��?#_/TL�dp�6YN�K�����:�3��ZI�l�bD��l&�u�a\/�6YF�K�)h�����Q2���"���w�>�x�:�����K�jz�������4��X��s`0�|B���4boa�.k�0��=t]���l�?H}�����$�(�4�:c��^taY?�r
�E�-��1�������W��LU�P���d8��e�&���m�\$�/�n^W�V7W64���SW;
�d�-���tk�@�4^��cPv��g��li��4G:�bFE������Q/0�C��N=b:I��e`�j�vT,T�r(&di�N�<��z�
�.�d�F:Ay����zj��hL
��>�%QT���)�i�Z�s�
�d$�HMIT$w�i�����b��QE ��C;x�y���Vm�wB`'�%Q���9R�����7`����R�d��,�.�c�-������,{~wDQD�>������k����/��
b��'
����
��k:���?���o�I���5"j�����#@����.������^�Rr*�HoZ�������F�`{b�~������=��-gWS�����F�y[q��lp\	��-v��>a���?_���s���}�.�zV�eF��X�D+^��I�*=|/
�d������g���ui�Q��#%��3��NG� ���f����9�t3�K�X[-�{�b�A0O���fRPSI��
�%rF'fT\��O�x�:JC/�_����<�-F>g�����C8��5����^��w��DN�~���1h�A������{d�?d����?*��?��r���)���E���@��	��b���/��4��n��n#���f�0������V�
��������
Y��(�if�,��>��J	�k*�D�kG$2mE5�i���LeMVN�vP��$�u�p�~B��Qp��6='9�H����-I7��T��>�GK�W��~��W&�? ��F�y0����x);n����o9H��=5�M6b��o���1v0'/�_�s#��
�mo�N�������q���C����E3���i�BdF������r�v�!�Ej����*t������e��u.Xj��w'fg����kOyc��K�����-�����'d�VSC��SS%�5�J5����d�@S�J�X����@���F�*��T{�q��V�����R�5v��.$,Ts����������\HS�_�R��J[�?������zXi:qi�rs`��<����7l��������$��4���j^����U��^W=�H�w���~���9���:r
����
�����(�[�������K��j�.>1_�����N$����:~��:�B��^�y�����%=~��#8���rB�G���uTLd�
��^��|!K #N8��	n�5vQK�s�#��MM��cd� W�k�G�{z)P���+�5;-��K�@�POF��CK���CT����WPy��GN;jy5���p���$�?"�N���v����a�r��Z�e�|P����.�u��6�3�^�rluBe-M4&��A��*E�i�n���O.)Q9@KG,5��x�Qy�L=�����bF����F��n6�D��Oa��tq�D����
g�}=�G��3�������p�:-�"�!2��
������X�}t��~���+�b6�<=�_�[K��Q�K�==��g���-�R������,�����-%F���b�kI5�$'g��/��g�)8��~�!�O���q�
�'����S�*�mM��N-��u����b"<��x�9�d���t�T���fR�����9��%�H~�����d��_Q
%�x�
RN	����;�}����-�K�3)���j�o?hwWV�?���_�
0002-JSON_TABLE-v38.patch.gzapplication/gzip; name=0002-JSON_TABLE-v38.patch.gzDownload
#21Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Pavel Stehule (#18)
Re: SQL/JSON: JSON_TABLE

On 23.07.2019 16:58, Pavel Stehule wrote:

I got warning

ar crs libpgcommon.a base64.o config_info.o controldata_utils.o d2s.o
exec.o f2s.o file_perm.o ip.o keywords.o kwlookup.o link-canary.o
md5.o pg_lzcompress.o pgfnames.o psprintf.o relpath.o rmtree.o
saslprep.o scram-common.o string.o unicode_norm.o username.o wait_error.>
...skipping...
clauses.c:1076:3: warning: this ‘if’ clause does not guard...
[-Wmisleading-indentation]
 1076 |   if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
      |   ^~
clauses.c:1078:4: note: ...this statement, but the latter is
misleadingly indented as if it were guarded by the ‘if’
 1078 |    return true;
      |    ^~~~~~
gcc -Wall -Wmissing-protot

Fixed in 38th version. Thanks.

Regress tests diff is not empty - see attached file

Unfortunately, this is not reproducible on my machine, but really seems to be
a bug.

some strange fragments from code:

    deparseExpr(node->arg, context);
-   if (node->relabelformat != COERCE_IMPLICIT_CAST)
+   if (node->relabelformat != COERCE_IMPLICIT_CAST &&
+       node->relabelformat == COERCE_INTERNAL_CAST)

There obviously should be

node->relabelformat != COERCE_INTERNAL_CAST

Fixed in 38th version. Thanks.

Now, "format"  is type_func_name_keyword, so when you use it, then nobody
can use "format" as column name. It can break lot of application. "format"
is common name. It is relatively unhappy, and it can touch lot of users.

FORMAT was moved to unreserved_keywords in the 38th version. I remember that
there was conflicts with FORMAT, but now it works as unreserved_keyword.

This patch set (JSON functions & JSON_TABLE) has more tha 20K rows.
More, there are more than few features are implemented.

Is possible to better (deeper) isolate these features, please? I have
nothing against any implemented feature, but it is hard to work
intensively (hard test) on this large patch. JSON_TABLE has only
184kB, can we start with this patch?

SQLJSON_FUNCTIONS has 760kB - it is maybe too much for one feature,
one patch.

Patch 0001 is simply a squash of all 7 patches from the thread
"SQL/JSON: functions". These patches are preliminary for JSON_TABLE.

Patch 0002 only needs to be review in this thread.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#22Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Nikita Glukhov (#21)
2 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 39th version of the patches rebased onto current master.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQL-JSON-functions-v39.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v39.patch.gzDownload
�P��]0001-SQL-JSON-functions-v39.patch�<kw�����_1��Md���%;�[�QR�:��$�{���9��P$��7�_`|S����s�F9�0�7��"�A��{������A�hw�G���k{���h�m���6y��d�\��v���O��v�����K��P��
?�:w���\Z!���u�`�1�����V^����)
��;����1i�O����1��{�ve�?0=8!�]�fg?�N��/2��E�����,B[L��+�w�c�4�%~�������p�R1�;�7�#��<`��J4*4�
���w��z�xp�|J�]�c���q�O!���4�
B�9o�K�h������_p���?!��% ������e0�z>���B�#R�A
Go��[����_y�$h�E�9�?2�hw�r�-����;�}���'+�id�}az�?�_\��`��������v�<7�`8,���?�A���V�.4���j�e�v��t��G��EBF���G��
`�)�V)4J����]��l��dxXL1~�Y��R��A����N���Z�;��������y-4U���p��^3�jF���-�,38W���r��ZK����E|
������F!�G����r����- TQ@v����P�Sh�-Y�C��]Y4x$�aN�(f�E���^�LC:��^�������e
�oE]��u��Q���k+����KC����F����ATCg�����s��[��W�
�rz�g>o0��N����������WEr;T&�M[�B�Ek�qt	�����AVx$R�H�e�� �=��EAe@���m(9<����%�����z�<\v�JC��B(��Q+ �+(��2W�BX�\�����#eR��}�l�~PB2W�v�`�����5�@�Ac��Z)�����������K�B���:��J�1TB�z��M)}X��[���y2��A238�ZD;,���>�.1��f
>������j�d$�U<z�F2\�%@��)~6�H�C���{qZ����S����|�7���ZD:*�Z�a��e1�-3����H���e��0%
����O*����CJi��������.�</\m4
�@�q��M������?,7�Y�����XJ����q,�2��;�Vp�2�-�&z���{��Y���~K�%3���s7mP�K����(�Cb0��[�}�}Bp0�W��#��vp9�O�����3d������� �MUs� ���m�����
QA��B����?�6�s����$�$�SQ�x%?�D��a��?&~��|������.}_\N�|���E|����|F�.���pcG^���E�	�{^!���������*�k�BH����^��4�,�s�u����f�D ���:����l��������,?��j7^�i|��� \b�(����9��G~C�>#3�����i/1ar"����������z�� u(��������t�DvW�u2w�rD�f)O���{�S����t��>@Aw{�����$�.����p�Ujw�(��,�-E�Y��t����D|R����:D��N����Jp��Q�S�E�&��axQDe-����P+d�L��W)�dK<U��j�j����&�K�������TS����Y;�-�LU�3�@p&c��_��q�� �l�����������e/��CI��6?�e�������Z�fa������P����hs��%,�>�{���;TB-!�5�*�tB`hI�.T�h�Bw���}<�YK*{yO���hvG��>�>��:�(�5�ra��Z���!��a/��w��.���pg���~[����AIVx��%�l���|C��{������n���$N-F�	K�;�����!��+��j)K�i�p]�s	j���(r@�$�e�I�N-�VpOw�M��k�:�J���&B��|�K�lazp�C�&���4���"9����|I������v������|�����}��]��?�@�X��r6�\�.$z
j ��VU�g��)7�%G��t�(�q}.����a���c����@=6ur\E��D:�e|F5�{�BJ��Fd%�J����~�F�[���Oc)�Bd�G]�����^�CX�T7N���N�����R���^$
t��
J�����Q_���L;.I ��}��k�K�=�)��&��������T�qI#*L��9b0&~t��37�m�@X &�A�������w
�5��W�4^>q�
� �}L�<9���E`;G
/Z��l����
�c�z�>��f�����}rK}�;���H�pg��($�k^=P����$dv��%��v@���oA[t�(�F�
2���p
2���@H
�DgD-��2a�A�Sw���~c��\��#s���; �������A��Z,�%�ja�����o����.acz�y��g�2t����j�R]g�}M?�K��B�!@��Y����K��g��z�6����GR�	�����L�)m�S���)�S���>R����X�TN���ehQ�����:F:6=�8�)I��V�!���I�<^�>���~��K��V���n�U�lw ,�v:�b/F�ooFo�Dy�
��&�g3�3zu1&�����b|A��7�
M�3���A����b��?�mg�l2���jB&���������<��++���s}��Nx)���:�*���������<���Y]*k��7-X���q,�`��!��M������ �Z^5)����o�$R['�������f�h��T�O
�\[�bK�e�w� I��{[�a��8�qX��9����0W�?���xv�F~?�����Q�����N�?&������]��}�9�?���_��_��w���l>��"_/��]��cr������
���������s���*��.�
���!��R����i%P!X
��-#2L\��L���OhDOL��(��j�;6)^X�3�&G6"v�w��"��:�e���g&�p?��	��(�d���W��-z~a����������b�lv�}��:���"�-mQ/����Q |�9`���,^$Od�.�g��I�e�V`�~a�A�p�-�lK\Yf��[��-+l
����?�"��^����Z��|$��r�Q�?������XS0@��A�Kq/�(b��n;u~�� ��Y,��8���R�v��Wj���p�Rtn�A�0�M�j23mQ[�v�f��GWx`��RL�i��Y�uq`�G^����y�QK��/�YZ��M1�����`�s��{����k��8nj�)��(f�}vB.o..H�""9�|BES<���jTL��yeLNa?�5��9��F;�v�w�@���O�`v�P^���rF�`,}�C�xn��o���I����B�p_�H�W"���"���m�<x()t�(�������g�e,�#����v����~�^�sVA�>�3�!N���r��=��'Z�3g��������jn�('L�
=�h�JV�������Z1�t������x}u)���%����:W�2vJ��u���:V#
���0j���_M5�HuR��
���A��$Y<���p�	_"�c|
Nn!�H�u��^��:��C>��I����}?j�tc�I7��qL�Q`���I��v2��z�n�t����&�!ok�klo~�F�k|����6�_c��5�1���6o~��1?u]��	���������.�-i~�a~G�z���;YJ���
:��V?��d����m0:I��U����h����	�J��iS�����L��Y8�\�@yy���h�\�[���Q~���$0�I�H���@��"����|5G�����'V ���F���-��aw��
����a�U������Ex2���i�cF�{X��
3��6�A.����.
K/�W\f�W��,��;�
%�^"8L���P��A��{$�X�"\A?}�,|��s�����������b����]O��;M��"v�!)���%z��;�R��?��U|F�YT����G�s��f!S��f"����k�%�[�6��~1�������U ;��'n��a;~��[�+
�f�'���dYI#H��Nju�6�6�[�l�/����dbU���Joi��P�c���7�4��RR�[#�b���x��9I�=����\U�l����.��M�������$�n�' W���*+3�>�N�����O�xZ����~gR�t����"�we��������Y��1ty�!��.|av��ay:?K`��96�J���T�<Dsj����$������no�Zz>6S�p�A��*�ok&�Y1v?�u���	n��zZ/.��X��\G��g�����X���]��%N���#����%Vr��7�`���,D��z&f�1�>�����z<U��bp3�����q*�s��3BW
�}@�E���|�����xqo�C�\����D����f-e��k=o^	HYg���m8������T��A�<�'�T��l�xa��B��)�����Z��Um���@ f*�O�G�j"�F����M�&^�E��dl�GY�p�p�L����{��~��-�B��^d�XeS�I��s�E~"&��yR���b��qq�W����C�72�fE^���v(F��}Q�YwV����4����8y��Z��N������4#��b���9���J5�/O������A���q�������K������i��,����jR'OB����AC
�9���	�����I��b�8�K���o���
����zL��7_����n�������-NQ���e?�v�f�R�<��2� 
�[����C��6�#S�������[�����V��l��ZQ��W||
��g�^c���wtX��IM�bw9-^��x�S�qe�:5V��a/�V�T�}u�����0'�A��Z���<�����::����0�@����r������w��@AK��6�JE���+t{+w��|����Rj�������HM8K�#��Y<��n*�Qy8��o����h:�x6�����W�jX7S��Mo^]_�.s�G�lev��8�SK�QY�<�����v�^������������6�K4���73�����������.�D�.>b��;���&@����!��Z�IqI���l����������.-���
���~:��Zf�NX��O8��4���*�e���@�)���Z,�;XK�]	A$C�"���Gj���Q�����^�r�D�D04�GSp���Bj	X�y���q�;^�[� .�F���O\@S�7����T�U'��x@���2�'T�����["�0g�����
����p�����+	P-��dr��G�,	�E	)=Yb��gZ��j���Llb������qU5X�t�����QN9�^��r~5����g�����)R�2��������_�e�OR����5F��xy��?��kq���}��8����o�z���D]�z7>�=��+�
�]���m-Y���8E�+���	��]L�@��rpuOJ�n.�~y���@���K�GL�jKp����J����*k��JC%�(�������RG��4��p)���x�Uq��a��Rm�v����]��W����5'���C5�,�5_�~P�:W��;��9pUg��r�m����D����6N7���z��w�����i.��"��T�d��b�������%�(����2{���h3�����~���)z���F83V)<K�S�y�k��O�X�!B�(p~��tn.����E�a���V<����h�w���a�O��H��a�3�e�[2#����`����������K����[HjI`{z���7�\+��t�s?���IU�FFFDF�rqvb�e����������Gd�� -L�g����3�<���L��!�UW�@�8I�O��9"�R�f4���)r��	Fg{���nD�[��OfF�`�I��F�$s�'f0*�B��Q7�EC�l��4��	.���u�c�1[(���%#�M�����";��R%'���P��������+D��eB�������7�. rsPT���R����������($���=���/NY:�6���c����D�!�FpXP�4��8�(���>�A��H��A�4!��F �$��
���>�(���V��1�l���t$����4v��QM�\��,��p�W
J��D���e�S��]+��`tmP7L����6�F���0���`�BTt���������~�/F�}�a���T�G-�`2 9���pg	�^Y�%�Fn�z���u�`��g#[�40s�QK�X����%����ulv�(�-��A�a�u��Ti�e2��1U	s���jf!C��?��5a�����j���[�e�5���[�\���H�PS/���7sdT$�%�T��j��BI��e<��SL�2aX0l�����d�Nhq����D���������G;M�����v�3M�L���L]������������6����d(��Y�f����2���^F���
N�*�JEM��
��4?cD��%��]�w�P)4y�V�,^$,<��T�/��j�;	����p�e�D���\���NQ�L�c�Z��S@����1��v��,U��G�{#���-f�<
���D���)�n�?H3��t�p����q_�H,��K
�.�Gzs�N��P{��+�����]�i=����u���
0�j�_��wt�`�#�W��RI�����ZM�DB�M�o]������m�&p(�M��Y����s��l�=/�i��+;0j.<:G�Q��I[���e��8��G���@����<���pZ(Mj��f��#������@������f��4���<��1�\�1
��\��#kR�3r�<*-�E�S!�����5B��%<[b-$�2B�
�P��V�7]��W�p>/g����E�Y#
\~�dl"��a=b�����W�1�e87!�c3zrd^�AN���.�9<;j�����?6�����@�lyG{��J�7���X�k\�4o����3������m��~�l|3��gx��u����p��F8���H�Z�������H�����L��#��@��;��;����*�4���x�=�q�*�bh���eZ�����������r��������}�Tc�����$�2�4���z0�"�RvK����)f�>�D�o�t���T@�AK�B�IB��2��R��T��n�G�[����Q���y��My�	<��d&%GIm#R�'_t�j�o�7������
��.�}�Zs<�U��������!QP{�������g�s4aO����<k�0	������a:�D��F<���@��Q��OQ��<=��o��&�Qt�O�����{�A"��1�fk���e�?��B�}�m��R�����U���TXC��Q#����G�� wL�w%����ygi���N�T
]��M
6�YM���.8X���J����*����%����.y��Wa�1�1#�����i:����w��<�4&V������� ,������67��L*�&�d1I�#_��:|��p�CWV���{=��y�s�W��fOl�B��s��'����� ��i�W����7S��������Q����K�]OG$ZR�����W�|��[dk �/�<���w����c*"�?(>!�L�#-}���};��pN(���[
���Yfg�X���B�\��e(m�'O�����2�#5�N����������������(6���G�p���c�����U�7��:�5��6`��B�skM��F[��9�:R�9���V�gY�{7D�����v��/��P�)<��L{�����!���/y��;� }\u_-�� ��]�6��3sS=��q0��9c�c1�t@����=7�����\���N����M"e��������3�YA.N�A�?����-`���3��5#wl���#eg6wmLL��r�������"��B
��Q��.
m=j���~J.%�x2�|�%�.�N�$3D$K<k���JD�cBw�j��������Gq�up�m��|���cD0=�'�q>�(ckV���{E��J�o6Yh_4�����yT5���_��W��[��;�Z�6�<�U��Q����?�
ia�+�o�����#d(��o�*Y_��M������u����\�����Kqy�/l��ha�=����c0��<{6��������x�>?L\�G��X��`l�K�9�'[b]���Z�HJT
�S����8=s7��z?J9[B#�Ws�]r�b�W!�>$&��*��"��m^g^��^3��6�$�@��#{�V��
�,��������0�[������Q����F�'-�f4�9�%�{�s,F��Ay����CF|��Q�m���u��ET�.��2s�c4D$9���4M�3O����X��z(s}m���HR� k`X���N���*ON��	�����n������Zb������!���d����.�$>���1��n
�-�eYHI":
�	��,����e;�k<�E�os0����d���2/Be�4eJO��Z/o�(cil��h�
?F������p4~�-Ty���i������a�)%���"�DdU��K���)�������.yd���t/wP�X�wd�����Qt�pc����<�dVV�������cxt���cZ�p`�B���m{'�������������!�}����W������leL@����l�#-�Y�J�~?�b1�2T�Y9�E�n�%��T,N9�	�s��l���	�@7�,�LVfxB���s��=����Z����-�����)��C�����������L���J���&"�L�p=S:������s��z��-��D��+����:��5^��j�8�?o���`�c��=RJE_�ollo����[W�9��b�d��c%)��F���';�b�v��+R���#��ON~xK�q_O+�S��X���JR�E�-ul:9:8>�")��u��k�k`�dL�l/���r�me2�6`���n�E@��vrp�z!Y��.)G5{NQL`���x��=�}��W�����v�����nwg{3������-C���[���I�+�X���c���<Q��QA��}xv��RV�9n�U:���
c&���[8��L�%f�������uJsy����N�M%N���[J�r�wp�|�ad�~�����u��^����0��'�B��y���=��u������F6��]����>�,`��
�i6D��x8��������D���M��,8Y���FC2�7���F}OC������������@�o��*�~j����:d:�0�i��t�������y�<������""�p�����h�4g~=_��A���u���z��V=�&k�ys5/"3U"�5�D,��Pn�lU�i���4������T���d�W���"9+;N�/�b$:��=[�J	_�����Y��@Uo���@M9��E���
Jg��F�w����.Q6��h��W��
����tA)��Y�����6�#�K�U`�������-Borw����6�����{���}5��i~�1����o����%w��l���Gp	,_�;�F��E�2���c�:���^�p��[e�/4M��r����~j��*�M�z��.��P�� �4���Vo�sw�)�W��V�����-
�����~�]&��_,�Nh���y��E����Gv������d��=y>(��EQ~���Q�#>��k�����C�w��������ykG%�-���K�pD+��P������`��L��0���!�[��ab�<���#�g�om�c��JQk����/~�1���������\��`y����`5�-��6��;��@�m�N�(]h�`g��+�8�/�����&�$7�����;���S��Fjk���e�n
��.���Y�����r���q���,J�1FlD����
��KD�7�����4��U2�	�Kw����K���~�|��}4m!���j��]��������\�1z
�L�8 s�1^�(��������k��1!0-���]
S���~���Ht�]w�6�����?�������G��2��������P�O�t�J��{���z��p(�@������[��;i�C����eNW�"DU$F�((��<����g����X�Z��o.�>$	��[�k�Z����[{[�m�I�2��;��b�	�nbTj2���oya^�H!t�C
����u�'Xs�r/k���XS�n"���)jH)�c
i�xQC�� ��ugQ�������B%PaS$�D�aUcQ#Z�k�h�J5�����I�Fs��UfE
Y�2��-�,�\��@Q�J���������)�3���a�V��b��f�4P�L��h ��xZ|��OL��`!����a�M&��>�O^4O��&��.��k��n:�<������w{�����������^����i"f`�b��]��3
*4����A�-*��\4�,n�<��p!��&\�9fp��.T���M	N�d|��n�p�5�����a�X���[F9��.'�>X!���k�����l`E�s4���8�2�:�2Y��,b��H'��N��������[�Dh�6�k�u^�Lw4�����[�� ��B��+�mtt7�����YG��3�B��A�s~:�D��ky���<�'_���L�2�.2������(*h-BD8t(��/�2hf�h�9�r�-�~��$������z"Y��?�����|�]��fv�wu�%i���l+����-�?(�����o������#Dlyw��F��s^��{�La�*2$	9����2��"�^��o$3�(�"��F���Yq��1RJ�8�G.s��s������x�r�a\�K�@M�1���J���� _(��[��[�Z1^ �F�r�Z��9)B���
�})<���W�9�^}�L�7{�e*�Uu��z��g����}<������-t��������
��4Y�R�r**��;�rs��_�4�p�y�����y?�I���X���es{��[[��^��WE������.C^,{���GY'��K]8i&���2	�
u�q&�ppw}�
���k��#��������H��W.:���l���Q-9��<������� 8g��o���~��}sf���b���c+��B�������)S�N��V2�Idv;&�-�Z��tOy����3�p2e	T���q�:��Cd���2�p�=kx���7u�~�o����h�q����;W��W�L,���R��o6|�;o���������QS$j���6����c��(�Sf`��]��y��^�T>#N��p� #�aA^@���l8�
l�����v������a�]���~Q��v�n}���F#Vy��@
�:�D::>������
B���f�y�%��w��r��"��l�F �V]�BF$n��5�~Ra���-�g�5�o#������T�)��k��
���L�	����c�e�C-	�h����(�f'	�D0��3~!|5CS�6�����P�^[�.*�+e��(D#	�B@n�g� ���+�"���a��z�E�nE�����w�)�b"�]�T�[$3�G}�di���g���}>������~:��������S���J���]}5� ���vaWc�=��k��+]T2�3���)-�f<��9��!������{���*���JO[��|�����G@F}�(���i:I$�4��f���)���
e�^�7,������7���L������.����_�l�������@W�C1��NP�"���OQ�K!��A����������5�|MAGD�0a@M� �i�����?�����YE�,�����byl��nNE��YZ;�_dR|���j��:E�-�h��ICu/����Ym�O��M�����z��3����f�@�$m���F�I}�8O��x��k�9���`���a^��}:��+�O������.�)����n��F)�y�]���[�����6Of��^���23����4��T�x�l�7j�]�QN�v#��t���"����1�=K��U������3�?�c�"%�����M����r9M��x����&����W��14����a�yv��P=U�rB�9`����eo���b���K�L������,�x#��:���)"�����lJ�IrHc�^�m�(4�����4M��:�_����Q���p��cUi�R�,;�S5��nT����N(V��������O/���:[��qr�6<�{�F���2m2}���n��1
C?z:Oz����;�Nn	w�����%x9}��L����_��&x>pP�>����u��������Bn�}����B1��������
����Sd�����������~��*����8�}������sOB�Ve~������h���g�7��FdZF��C�-������w
3��`
�������w�"/jx�Ts%&%�}�:h5UIE}��G��u��������L��5
���&���X�����5����>�����?&x,&��/Dd��U�� B�l���P��@����
��
K������]q��,����A�,^�������������\"��fV�����$!O4*��� ����5`IBY��\�,����5��!O<*WY	C�tT�2� ��|Z
�H6�~^�)G,
	K�f�o�?P|��$�����n������x`	����vdlQ����^I���B���7O)W�����<��L�*��nNE�7��][$�.|��V�E�0Gc��-Y2,z��V��w����)�1c?�F��3�q�6x��aM\�{�=�mkbV��=/�i��:w�V�a����g���~w����y���]�c.�d��sx�8�����@�w����Q��\hiL�����pE����t��0��/L�>�y����.��c������%���������z<�.
�o��=�@�$/����jB��&�?�[�C'8�.����g[�$�=����c���P�N��[07��c���� a�`���
|#yrLva5��k�{���Q9�����WZ{f�������/P��$�~�$������4 w�K	��W�V�.Dy���X]v����zcm����4z�V�V1�K��l�!	|��>���tD?]�8��!2h��/�[���w�����i+�4O���"c���K##TN��"��1��hn�.��������l�Z�o�
|��a�a1\8Y���b���gg'����*F,:�E1X�11�$���m��(a�������(�����.��|����0���!����'�=
/�E@~�L��kox�[��l�:W���7�tN��.����L��N1�zey�F`��e�	Mn�K`��mk��r��UP�5����R�Ko�`p��������@��uvqv��t�c�(�Q_Q���`�����Z��������++]I�]6�F|�
���fQ��xb.��&a������l��l����Jv�n����L��hq����ac�w��8:z�-�"���A�H����nD��4��(����R���(b�y4]yo��ts�XD����0����R&�D�����������u-�O��",�5<z�f~��-�yc��2a%2/����}����7
"�������wI���� g�2�����2W�0�<g�<V�c?I$���G��1�p8���sa4
�77�����$�0�8�����j����o/���V�Il�M/���w�����vV����6�2i�V�Q6�b�W������c�����%����X
�H{T��x�t3�A;O9c�����f���������^c�H;c�S��ep/lsE���$��=b�E��(��w9�z_�}	�h�d���J����"G �W��}{�(����K��"�b�W
K��R��3��W��g�+w��#���5s�hq���xo}5Jf����{��o$�C���������W�7v4<��!������\��7SA�%��Gr��@��(o"�s�4!����:�u#����L������53�������(���m�������|�b�C�W�<�%V,���.Bh��5#>�;��1��E2�j��5;'3ZW%�}����������bQU���&$�|�"$�|X��t� �!��)��)��e)z�L�~�\��&��}y*�P��x���,1����+��!�������/,%I������l�����5� 	��F��Q�D�Fj�Q6���]��E*Wb+LU���|�I���1����(>���������b#R���mqZ���a
������Br8�n���f��6U!\x{�:���|~p�:F�rqp�m������r-��U�[��&�i����c����"w�9}��5�[�Bi�1Q�AS��Me�*��Lt7���)*es�)**�����w
f�=�0��;��c ����_-������������������t;��"���_�|8��;�>G��yo<���gF
-'����������Zw�����W��[��e�eIU��h�v����h3d��a;<�b��n?l��Q`�g.���o$�B5���2?]I|��%M[���ug��W����9���T�5��
��CU���gIc�%��0�Hg�3������O�gA&��j>�w�k ��7�a���Lz�����]k�B"���7�����*/VLP�����n4���:�����2(�5��A^Q&�D�w��~N{7���K��N����u����z���{z=��:����8j/)o��)j|�
��|n/�H���w���	o��l�j�z�c�%����� <�%������sE�rv��O;��a��:�5�������&�At_a3L��?���Ll��0�����i��]�t[f�v�������z\mCz:�xpqpr�<i�;�<x�dE�o����t����������>��_1F��xcZ��Mvx����7�(F_cs[4��������,�u>J?��*�t%B����-��]����o���r�`��:�'�����@I*f%P��G�tGV����=�� 5�{LM����Q ���G��-}�.m=���z���?K���+���c�h��<�� ��HZ�>?�\�}����N�����N�s������o���.n�,�q�V�y���c9N���d3)��?�O���������-��{g8������;������#�&KG��D)X���&�u�tF.��Q�����G�qy�z��m�,�pI���#>�A�|�dzB���Bw6$6�0}}(��tk0G���N��}�Bp���K������8~
����
���Mo�hdTz���;T����L����0V���h	D%V��_��o�W0��y2r�i�w�
���[{;��?�2D�WKK:�m
T���^����6�w���3��X�DD*���S$"��\4����y�~����u������f?����h��l���������X�g���f��yv��u����D6����g~R_�jT#`�u;��J�kJSs���{3��.i�;.,�oW�(���,���M��s�������x�y��\��/NGz���R���pa�+����8Vg3�<�����Lu2k���pD�^�V6oC��&�p	�a?p����Na�p��{�Q������4EQP�GC����I���~�������/�:&\��F� �Ca��y��+X@�P�Z"&��7BF	 ���g��Ub
�mx�xX�r�:
�|�����D�U�Q��=�k������T�%��%�9el����u:��0>9a��������J�i���~���X�cT�$�W���r�)i�����Co�y��L����a�
��\�$��'��)�R?������a)R�m�n�Q.k�1"2L���/�#A0�`�Ig8�����kg����e�M �*9x}v�j�������V�6//���=�������M�y��o�y�Z��d���o/�������	�y�����g�zzp��e�?���G��������������e��;��<���-
����o������~�Z�������w����wg����L���&����������0�fr���?�#��<<8j�Oz@�Z��upr�-�������c+��
����/[�����y�=�=?;0�L���e+����jg'��C�������B�������go	����[�V��KG|vz���^���?���B�v�������6����L�[Q?���4���o���������%^8��s�as��q?Z���%���Q�H�9$����������k�-�WN����wG����������|{`Um�5o��e����~�������|�|x�d��������w�<j�&;:&�\�_/^� ������~�Gg���������p���;�rq�G��j��E�T�k���~�_.~>��o���wo�z;��? �6:l�#����w����������Y�	C�'�%|����3�����~�>�����h�-k<�F����v��
_��N�
Q�������4[0�7�DT�_\"�����'�����7g��6������`o.�M �o.��&o��z������r	��}Dw�&p��6O��I�������}{q�������%>8{w�O?}�TT|s�������a�1P\����w-�{��E�.qmZ����_�=8J�O�@��-q>�vq	���]���/g�����a��/�?������bR�K?#��N�E�����W���}?{�w�����-|��w�i�������?�{�������yN�tr��y���~����&|��q8M�>`B'��O`��@��������+x�|�~�f���&����_�i�y�������S;;����������P������A�?=�����an�q�k��Kz�x�!���
a�go���f+9;>�L�N�X��S��g���@���i�����T������#@$�{D���[��%g��������X���_����������S�}��Bm��z��k��������xr~�<l�H����<����`>]�y_����.�4�����v�x3
�p��6�7z��mr���l��;#Q�>����T4��?'��P���|'Fzp�|��7�G�T������H��w�������$\�7|m�@����9Ad?�����?a����
�y�r�E��������w�2������k�6����1|y�h$5��O�t�#�_��0}�<���R&)�q	��Lr�<��d����%B1�&�l�p�/��(�'���i�/���V]>Y�������6��w�������=����96��1��n�) �w��/������}�0���#�N����D���D��lF�_d����'� ��Z�8F�c���Fv�aC�%w�6�a�<�Vb��
p������c�o�C
�;??���!�����#�=��O����|����9�(}N��_``�
[ U�x�d�2���������v6l�|��d�?��<p�;��h�x�;J����m����>{w�GH(�OE�N�p���u��{`n�S�.|9�������I����%�; ������>ouI�x�&�.q!88|��mB�Q�/�/@�Idh��%|\��?�A�8�/?3�������9��p����@=�����S����������)r�	D�Z��'���?
�0��ZKX_5�R�����fv�5w���ba������x����O�d���Uc��T_x{
C<98����b�)��%����nQZ{��4?�"��-k�?Q�����:��=����H��O����a��~E��_G�Qg6����P!�fi���|�0���P�����/-���@H--1���O=�B�~�����n����
��r"�/����t���������	h,�b��L�5x2�y�mr
�t5���v��/�J�h��&3�s�!��v|���`��U9��r��C�%�1�J���Z7�w[RP<,��z�2�l�e�X�������89�>�Y2�9���E�/j�'ZH&]���U\�No��'3�57�t��O�#�/���m����+O���O_v��/�6{�`����{2���{����Os ����N���{����u\��O��
,tO�e�K�����v|gBZxV��K��lfo��&��G2�k����������q�5��#�mg�~�	n`����x���"!���'�t��{���`�r�K����]����$,�b���O���g��=_Z
�
��U`����
���m���z�����K^;����?�lh#��+�Wk�5��)���5��u�����M������"�H�/���R��$�
�w�,�X���y��k���L-0B	��R��l������=O=4�(��E��
]�t�X��{3O�C��-�,�28Sm�/z
�~�������Z5i�ioL������_6�,���j��_6��m���$� jG�OF��1�d"���`��$�����N�Wu���7qIz�%�0�]���6h�Kxkw[��v]
�(���b�pl9Q���^�?&C*�hI|i�*�^�4�6�YY)�/Ma��}%�EGM������{�@.�fK>���@�����0�e��PM��j���jk=����P&��1�Ol~O���
>��SnQ��$82��h.H������o Rj����3��:���`�~?�L��!�����Q���F���!J�"��3����0B��%C����p�:%�~RE�F���L�x]�z�F���
=b���4��)"�|�x�
����+�W�|3�O�e[�%X�eg��/>�L���[�����=	�Y_��m���lr^bU�<�����n��v�Ad�#�M������t>�^X��T��8�d8 ?�3��f2OI�����A�:V��Y����u�l�,����������a�������<c���%wZ9vbO�O���{�yu?u��W�};�T��m3�%<���rt0���
���A
s�v��Dg�qF���xL=��G�`�@4p�x�`?+z���,F�KPU�������*B��;z����cUo
���P���=��#[3rBK��e[�'OkO��%����5�*3D��Xa[��������X��]*9������G���A�~ ���P/K��3
�B��N'G��sxe�4�Z�M6�Jr$RBl�k�Q�R5_8o_��R>�&�K����8;\���R��[�U���];:��cZQ
����/��jt(A��E;O:��-�e����d6�z�������o"(����?A���o�j#k�c��{�qu�4�*f��F5�{�D��[������Zh�0�o���@�B��v�Z�w>F>I������-���:���0�V�j�>�%w�J^y
�j��gI:�U�f����|���Sla��-��3U�qb��V��2$B�N�I�������_|eF	������m��F#������	�<7ce���f���[p�Nd���*D�XXq"I��_���~�<_@�mK6��n����6��'}��-�+�</l_q���+��/��r��5��HV��\h�C5Jv��)n�ZI�H�\��W;T��"���N+���Y�8�T�gIY-�@^]��Y�g���gF���x-�pV'���@#�<���E�sx���k��a�������--OV,(�L�d���{`���������|�!���y�-���B���s� 8�?�vX�#O��}zv���t��'m�!��(��C�YJA�O��� B���!F�����u����U
4�g�+�Z;�c����Nk�4�sb�O>}HG��O~�88?o^`�Ty/;�s4�=
���a�k�Zu`oBF"`�9;��0�D;E
���UhdQ��Y����R��'��gv����a���}��7��A��J�4�������hP�5���*uu�Rj$��e&��������TO���:��R{��M==�e!��:��L ����3ms�9�e��'������VK`����u��/^�v��ghV�1��13��i\�����I�b��~o\���J4��P��6}��]��%���8;v����B���L��9����N�W���o:l(�;rO����%���Wy�.�`�P���_O���Yo�����7��%��$��#���u0���J��2�������4�&����
����kLk��;Ze��cq�LeY��5�S��1�7�j��<��?NNl�L��-7�~Zam�����)=?�����V��FV���q+�xN�Jj������0����~�T�w�s�#���}�������&�w��s�dM<�(�D(	�-�$X.?�/�;�S������������������
�w^�Z���F�[�X��-����k��&����LUZgGg"����I��X��������������s�o��>�BW\��4�J�L���,s~'�:3[���r#�����4�����h+��+����3W�`Q�21��cV�afg13��w�`�pK�0H9�9(�`��]��	�F.��,C��c�K����e��1�HL�n}w�r�&m�D!�u�;A�xZ��.`���X�a����T��J��@F����[TU�@K���&�[��6���y��}2�9�x����;VsvSD�������t4P��c���U��-�SG�X�`*�9�`��C�������nb�������v I"����W�Bq������F��	=N}-�����h�Q�2�#���Qb%|.�]g_�	�T���c8zx����2�fYy+��s���������b���9���sx?�h�ZC���Q_��d�&����MvI����Q>�l���]������s�f�VO�������l�������y�Q=�P��E����n��v�<�X���1���-�G�y$��.Xt	+
��c���*"��^�� ^8��u	\���~R�8��1�d`JU//$����Fa�'����1��jH����C����ZH�75����z�%^����������E?P?0���%����j<������[W����`f��*S�t�2#>�W�&_�VxD���w*�Rh1lc}�����Q��7o���#����B�3��*>��i�Kj��7������%���eG��'*�����H��wmZJ
e�}���T��P0n��J�����H$���<�R�4?.�/� ����alBD��Y�[]	]��������-��I�/+���C�����������C��2�m��	��~a����(�����g|�a?a�3���H&+�	��[����:��F����-S��N�����_�S������sh(�'t����U�'`�]����G�3if���%�������Z�����i�(����*�rB"���D�
���:	�,�5*[('g��{��z����t���4���D�^g�&�6�cMm��D��C��<r�MU�Ao��b�=@���;�_�}�������B���5�VW��������g%��[�[.!���}������m����7����Q��R�w8r��i�,c��l�*�K�dfV�4-�z���"�����/�O������������
g�AB�?��3m��f��=��������_����W����Afl�r8�C�}���ou.�����C������Q�oe"�P.5����a<L/��.���9N��A�	��J�C[�as4�~I�M���*����?���-��A�*�<d�mn-;�y�!����M2�:��Q��<9��r�}����F=����j�h{���dsZ�jS�%"h!�mq'Z�R:�w�0^0����q��-;�F�9���oOYoD�,?�[2NW��,����4����hO���j���t&�`k|�>�P -����!^�BS�1�+Qy��>TZ3/�/��m:�o�an���5Lp���0�wM��y�t�67{��<p`��j
o^�M��>5�:J��z�;2�3������\�+�9�3;?��������p1Dq�J[��$z�T";���X;?�+��8�9��L��:���I����+e���#�#C����h���[Y|��h&�z�)H���I<������h�o�u��_���?�N������h�Ct���Jd Y�C4"8��Aj@k�����_�`��@�A�c0��_��2��3���bPI�M��x�G�C<*�M$rkX����!��t1*�\3n��O�t.�b���/<���g��
*����i\&R�'9���S�,��i<���W0	����o�@z&;+(������3E�6�����+g<Y}gO���z��K����*���c��ip����<��l�MF�����������:
��F���.Uq�L�]�6ay�Z�&_*�45\HY�Td��	���������mg8��
�����Fi�*I.�5�6����\���5����'���/����|��QP�6����p����_�$�����h�<l�5nA�����a�"=9���!����$!�Vx�=�c��zB�+�m�,��i���45�6���Q@k�%�k�F��Q�)f/���.rx��8l�IWvzp���E��W���&����n��S��z�����F��(�����a��������M�]HFi�d�p���A��G����U�z����)|�~��PX-x�R�����2m���8�?vo��!E���9��O�Y��0�m~�a=�{kNg��?�jm�U0�0��:<�g�i�����y�v����e����Mh�t���0%k�&�6�>�D(�����P����e--�{�������s���,�U:i��)����nv-��^o�N{i{>�q^HI�g�;Ym�d�h�����/�����X�%�>��6�����2���SE�]K�X �_���3��/k��r@@�Km�I�}��5���s�X$:,��s�PG����W�:���C�4����=�m4���
�H��1��yiI��dM�N�ea��"�-�%�j �����
���'�}�]Q�����?��
��^�Td�T���%��;�2�*QfC�����G�/	Jm�d]�Q3��1������5U�S���7����pa�U��k5s6��y�8,x4���R
������N*������d���"�e<:���$���p�l�T����-/+[�V����P=4���*DG�mG��������S`�%���o�i>V�U�-�
H-0������D�%�_����O@�hd�lf���O(��f��W�G�O08x�I���g�l/��*�X��h�DMjG�F�O��������|��\����H��	E�f|I���b��-���������VTt�x�����j���'�V
�Xf�s�N:����C!�N��I^�����1���D��e�����o����c����8�`E�}v<^��r����!_�G������+H5�#�i&s����
��
���$�^&��t�_���$�������iu%Q��1���4�i�����9�bK���]�v<13��s��������`PF_�]��v��P��vdY."gZ��m6!��Wt=&�L�v�����N{�
�2��
M5	�V����O^$�)BS ^
��������0�S5".	X��\�u+U��Kr��r��m�d�7��v���������a��Z'Y�.W�����sT�%�F���`>����
� ���S�m-�4��{�GV	�d�n+":w�D��E�����e���,���UP���I��Uw����h�N�q�G\���������i����I;�+����Y"�����`�%D�\ ���G+=l�XS��!8u��T��s%���L�:d)��+4O�p�g;�#��1���CR���I�+����}�U�%��FR��hUru6��h)2����7�����f�I>��Q)aD-��U���%�J?��,	I��9d~�d��U	������	\ttZn�6S��w�����\�+�L����g���[7�'�>�	,�Vn�;wN875L��]_��j��N�����Lj�'t�4�%��r�v~1sX���ezsqy@Z��M� ��a��M��9%}��4��<���Sse�kk@( ����g���!��,/TtL;��Z1Q��-R�":�	�8_����b�Ob(q
nC���;�EB���%�a��-�j<I��ywM�3TAD�C���L.>��B-�:����I�,�7���0�.����
h�����������WOD�#�IX-�����Q���!48���F4$�X�g��Y�4���M
w�s��������&h��H��*_^"S+�?,u�e}bu]K���WFJ�#�(�Vi��5Hm�YDC��G�c>M��W�����
;�
�8����_h��^�K#��P9������������b1L�xCa������+z2�UT�+]tF[�b{�����SCV=������}�A�"�g�����	[����6o��m=,������
R��8q_|w6���q�yn��-���|\QA�5���ti+Y�+��?���k��!��\�aUi�UD�����
[VsmQu��D�)D
�!1�a[��sG��K`x�����
7�j��&g������O0����	������;U;�*�������+P�y�;" 8�'O|�W���"��n3,VDx�C��D��:[�c�5�@���%���8���Jo������Y1qA%&��M
n,4�=�`�`c���U��d*�L8B�'��3�e�gz�_?k���qcK"K��3[>�:B1/2.��8X#W�%~z@
-gs�p����=	Y����4}�$��6�_��F2%c��A����-Qi-i�q�`�h�il9t����PO��C._.X�D�������V3jj"��0O��.Tx�~wq61�d��A���y[�8�:�589>6��S�2�r�����lJX�J<��]sm�D��\�?Lt0�a�\qx�7	,)SF���
�u^�nc��}�k�L#���nD6�UY�j@�H##7��G
%�t�2��������qI~�E��T�H�R��(������v������F��h�6A�Up	���|
-s��!M�>����O�u���8���B��2w�-��6�0�����_�;>9���E�G�W�g�rlWk�$�h�]��t�s�.M��V�e�y-���h ��0"�)qN	& �mA@����OR���i@1~���EQ�Ce�[f]iN��?�!4qvu�����8�fv��\[��i�e��W82��?I��OF�]�P�R%&Jm$���	F�u��+���
��N��j�[���<���0�d�����{2�J�fv��w[����I���r~=����)��RarZ��R�����T�`8����7�4����Y�9�����zKe3�������k`�Wd�2���*[���L*�>���C_3h�[�P����vo|3�O�B��O��T��d,m���`�l�O�.E�7�L3z�L��}������9�-�wFE��i`("TQ�_/B	���5���l�t+��M����	#t�p��>X\MSV�9���*6H����aG�:�������r�>b��t�
�j;��B1�F+'5 7�fi��z6�K�����e�i]$s
	\���Y1��D�*��z<����h�KI���6�i�-':~(�+k��M)�%����%Ev��
��v���F��K{�YI�On�I����1�
%SE��J�������U�8�	�w�E��l_b��������d�y3��#r�ZI�n<I��t@��nP�����)W����D��,�fU���T�W���b+�Y����{���9'J��8�U��q��<�%c\y���,��^����H�G�
x�b"�?o����e3Z
#�	���$59��>u��%>@�3C�R�y1X�8
���7��	Gg��V!�PB�
qe<����������D?V��\�[��i
FD�w�����|�Q9"�F���G�#�F������|��s�d�;�Mmw�����'�~������O�}���Z�0/��������l��^�IB|���9��������t��������+��A?��Q�Z1�'�v[����S�JZ�X�Ar�\��^Mm&m��3o���yj�(�Y^O���y�������Hy�F���K:���"��rf���V��:�O�cO���NZ+�,����<d��X�=��?�����Z��*�]]�$�SNO�����'�:��E9�[kN�C����"h���/U����2�/������g���gk�= t���@�����3�q<
����<���X{����F���j�e�V��l���,���a2a����mg:����{K�@ t����}3�azu3���g��`�\����>��t��j���?��3���`�B�f^CU�5��&tNa�%@�,W�����F=V��� v��t��W��d*Z�1���K�:�/2�������"�_��W���{�NEf��U���T��n;�1V*�s�/�T����w~�2 |��d^<��;���)���pTA���^����~%��m���&^��6	�gF�2?�{��A^���*���;������8����1�����Zi��L�������=����=9J����:�i,�S�JYS>�u�0G��F�������{
C�<�yewI�h���K�v�EV�=}�l���EfI��@��W��c��'0����j����CQ���������F�e8��/���Z�F�(b�x0Bbi�p\B"�%	��5�FR�����#��D�(�>�,�6>�>�A����f'0"����%��7-IY�`Y�=�y�o�����M�������R�����8�X���y�"����K����!�D�v����8�=����d#���m8�O���O3��j�P�V�N��.V�����e 2,�"��eIsK���W� ����[}�p���,vaF�G�X���(PP���
�����a:�=Ih�����x'�=q�����@���_2'���:���M���q�qp��Z�J�f�e���������GX�zVd�b��0[��c��5���0A�����{+�C�d� 	��3r�eKf}HL��l���>�?���/��lC���C��r���9g�AB������H�M���^�������o5Q�la#���p�9��9q���ag0�=�������:�k���'#�`�W����"�Q���������,G(��Y#�<�q�/1�"�D����9o����4����u�4Ty#s1&�H�gZ��_T�Su���Crj�������T�E�s�p62�k��>���J������kF�>��	�z��V/~�U���h��������`���������`�_�[���V��\E����ECp����J����qRJb^J*���Z�<�����M==vM�m'�(�3S�yT�[sX�����o��m�������PT���X���mv��P��6�^�Y�DI/����/"���RBk�'�e���x�i�v�|h�+<��z�=�G�h�u}�9)���YE�!�E���X4u����a[3 ����1CG��+��`!�������ga�"A5���`�f��q�T��YW���+�=!�����Z�1�N�A�]��nU��o���W��E��}���
V��$�O[A��������g3�����/a�H�2kVV�����3e���v�$0�%z`Y��V�0J��A�f�O�����3��l~�]O:�h,��Z�c�Ql������������V��:���&�2��P�U�
��R�����6�b�8��-�oO����~�`���vY*�Q�$.(3�	���Z	���'j���'�(cx�F��+C��1O����I��z�8�k�}��t��� S�Cp2�(/����cW]�N/���2��r=�����(��h4��[�T��7a�N%����������r!�<����U��Z�/���A����<I������U�Q����0��~f*��L�d�p����c)��t��\#�#?����g��\��.�2^�!J�D��:�
��TUA�E��oS���\+�ST�Z�'f1X��J��"vGt6�)������R+.z�����+X����/��TyzR/�I�!~��98�s���"��E���{ �Q�_M�BJ

���L,2�>��n�<�0g��/���p�OE�T�r���7�n4I���X�9�q�[
�jz�:�b%cQ��m.dO��=��$nW���*[�Wq�t�����d���|\I��g}����'7h����*���D|�L�J�&��ug0��`V+���:������z��8!�H1s��T�Z��/��,���
��������9Wb<,���q��sm��0���83#e8uF�hEM<��Gm��
	�$��=]4�.�X�J�$�(���?��=?�<n5�E������)�L�B�hY�&�����A�������)�h%�����p|U��V��QH����=��g�vL�#7hyT1()�"#��	g���4g����3��9f'��t6�����O�$v�Lk�~����wk,e�R+|�"�g�~�k��)���F��p\T�KE�&�c2��	�����<�D����&~��R�x-�����7��}S]��>�[h��X4c��4���i�L���,bO�0F�4b�'��r�LNT	��N/�������V59�H�X��~�(�n��������i<�jm���������o���pv�L`�4QZD��\���e�&*��\@�A@=-�Pd�������(��MU�Vc1/�2���^�J4�%m��[�(5�Gj����-,�F"�OR�$Q�^��"���&�`����Td���o��6���^z1��Da�=�o����Gj��1^mL�<2���":T�����%p��C�#�4�����6-rL)No�b9`*��j�����k:�H>S�~��[K���.u�l�f��,����|CD�Ck�MuJ����H
�'�!�Ct�L�`'������h���}�S����.�� PE[�^)���2���'z���������Z�c{Fq7Vlts�N����/V�5ig�M,b��y��+4�_����+4�w����++~=�9y�
���M��XKu���rb{#'_��W}��T&�C�E�O&���L2YY!���z���I�"Z6o�I�}��YP�3hf��|�����}�u�4�U��^�F����	[��T�A7K�s.dep�Z�������A/�HV�x��NM���.�����{���e&�
g���H���3�����k���������Q5|'pv��d��
��S�N��A9���r��h�2�W���E0�����yV8`&6/�t\����.���f�S�K;b��:���������*Y]}?�'���i�y���5�����r�Z�%��2��~�9i����kiwoc�j'���oon>Z]]-������R������6�k��
}nl&������4=��p���1�h�]M��mI�r���^��Bg��|��rO�|
���Z��w�����V��S@g�;�����lk��Mhw��:�g�}���o^G|�P����1�
��	E6^($�tg��$�������o��z^�.�3+��WI��*6���]��B��d�L���o�,�J5b,����`6�E��jo������Kn�i�v�����[�5�v��������f��>-��S�����N��a_?J����7��m�,��OA���k���-|�h�Qr*Hn�~�c�N�������t���D�!��a��!�����#�������l0[cBT�!:T���!�����|����������?�|"��LP��b�Y�3j��2��t�4�x���W�w3m����0�������x��r��%����v��F��U=����nm��z��x�y���.��ON�[?�@����qR���}ye�,�������@�6�P[��fg1F�P)i�s�����:zI�Og���kx����hhY���c3�n��gv�
-V����7��p����?GZ����k!��ng��_[���n���� �@�d��m���B�$!io��l�~��x������{��3����f~3i��y�� 	�s�����'�I��oq��$�l���)�l�$�\�Z������6Hgt��G���$a��-!�����w����
��|��-��hg������i��i�d�7����P��L��;*G�g�	[EE�O�����$�
���Y:��Ab���1Q�H�HVU�������K���:�s@�=8����@a��o2���a�B�#�%�����T��FN9X�.�J�W*�aJ�'fN
�����gj�W\&du����%����8�)L�K�9��s��{�|�d�.������C��u����g!��s�};
b��� "@$�I�(�P��.������Q��N���6��N	6"�M�D�;�6�L����n�VU�:5Y���l�6m�}���Hp��.j0F)���
9>I?����3<����PC������nQ���P�����_���z��~�:xM[�C�������
/a��(/���y�PPwGI`�wQ�R��w�M��
�����$��KM�����9��8�d�>�j���v3y6�@�+��k�91�>�L���3K���U��B��$L�����M��WKIlL������t��������P��MH�8n���6������\����&v�����y��Y��D�����]o���u��l����������R�H���=�I�����
C�_H�9��BZ������mNy7#7W���{su�J��l�>]�'�}�1����L�/�V~3_��A0u��������i��0�=1�!�7s$$F	��
�Twr3����~G�5k�����%�ZZ��?�7j(+���=I�_��
Oru����B���Xh�}3��$����v�C��'�t5�eBa*�VZ{�b]�qS!]���b;�I?������m�n�}�<�cB����`��ot��)�v�x����(�������h%W������1�(�
�1	lk%�+��uz��|�p�Z�-|"�p\�_���������<��hv���$�$p��ASgr��
V��������Q����L��5��Oz�?	�,$��-�G�M�- �6��c���b\B��z����4�w����������!��U�����������%hU!�B������*����������J��v����^� �>��J	���-���Eoi��;c����W�X�m@eCa���
z��G��������K�+�)H
�Qxm���u@�FO.�o�)J"}��������5���t��o���%g*�yM$�l�"w�U)�CM������%��R���"�Ze7�T\@E�_54*����R��Kq�I���h�r^3d��qIZ�{��f
�?Cx����N>t��EV�K:��
Rb���
�1o0���3R�1D]�4v���i2��Fg��2@��4�}IV�@����DF{���e+��$��1�[4D#������.bxM�a���X����49E^M���2h,�����8��w�<k��9d��D^"9#L4����������<����w!8��������5��9H��hfB2���P��]�@,�	�9n{&�d�;&��y#���I}�i��-S2L��Zz`n��p���/��(�����6���kw�V�|8h��B>��a����)����1s�4:O�D��d<�%��7B$� �����p8����8B���*������Y�;UT��2Sb
��=Y!���z�+Q�F�����<U�O[Or#��XB�h���x��Y$����0X��<��t�F�M�T�9�I����1��J����PT;?��l���G�j���n6����<InJ��&;t������!'utt���N�XOz�����1�w:����Y��kz���5��n���Qv$Q+c������L*++��qx�S=�RB����9v�e���UK�|,�Y%��ln4��l�)A�Nj5�)_����2�����"|����7�Y����WKq�eei�����sl|F)��c%��|�V8*��H���@��k1�"e�r�����Q�=��R�i�l���=�@�j���*�����+�����|r����P	5��~�����ER��*�"o�k�?���8Is}r��y�%P�g'g����������`&�K��szf��Z�1K(.����/��z����VZ�o�v�\��!����{Dw��{k��J/]w��mm5PN�?���������|�����k�1��Q1�V��O�2���;[,2uJL�F�>l������x����R/��v@�?<����	@L>�c1rF���A��Hz*����tx�����x����P��M����u�PZ���&�����+�!�v�'��m�m��}������E.�1��g9eI��=L���#���
�I��Ne��\r!|�'�����LK���<e68�[����l�G����i��8�����a�U{8T����!�X�PJ����j"��X����#C�I�C&t�=�t�!C���'�AE�/� C���E�\�<�S%Y�/����d���������E���FC�Zw$QZ����+KlV�u�r0�(

�i[]���7w��lol:���c)/�tb,��O�*��y��2RyO�����~R�xt�c>�e��k�A��z p=����
,���rGIek�$������LPY+@P��/'�P��Sv�����F�������#��!_��K�K��e�����c������\E��s.?��y���#�~w-��Rz,%����	r?�R�U�Hi�Mj������A�_����x��e��U��9R�������1�w�3��l��v��P����+C7��d���cw��}�j��/���W�i�����
��RMx:	z�v�l!+����o����[R�<M�)A��� HQ�_�������,#[�%�<p�d�,��V�Du�k�"�i���M�UX7�j
��Ha�[��s�O�-�����}��������m���JDB��\aAa�N�v�n��5y��nd����a_�Q����9�9��Q�K�|b��cAJC������U��G����}���Fmw` ��Ap�xs�����!�������t��}w���11�{^�x	2H
T����d=�;�!��`���Ue�..]�L�s�h��^PF�LT��S��������e��u�7�Um	����#2q�/0��t���3 �(�5�C���j!�,�HE�p������6����y�T����z��k�)����O�aQ

 ��<]�~�
~�=�T�����I}�
+�by�S�)�56v��9�<���}k��d�cO;W���o_w���jXnh�.�w	B;��
��Nms��%Z���]_�U��������a����`Bi�������_!}FAr7z���iV-����i�}�*��FJ��'�������5�^�Q�X�Z��%w�lOE 2{K��%���O`�6`�����BeL���4�!�j����*��/�?��I��e��X\"S��������g��#��Z���7�]���-��t�E{�5+�d��L�&�Z��k��%Wr�F���d��<�~a�Vo~�2���"w�����Y�ld�h��,��?�B�SJ*C�2���q�o�2����$��w���N[��'���}�����a�yD����f����D��P%~���27C��������p@���@@ln��QiHh�0�X�x.MQ�+�����HN���3t��J1U�DE��<�	~�qbo��NvJ�Vx	�^�	�)&�b{ouBe�r1f;}��vw�?(�m�s<���Iib�yrl�(M
]�p��.�P����Ug�|��t��O#��A��I:�\H�?
Fk��ssP�;�Z�]�a����<_G��wj���D�w�������L<Y��dD���(�E���h��?����}
N�U�����n��nl,��_��bx���al��%-�]�����PKU�P_�}�w��������W��Q��G�
��&���u��������������L������K��*!��3�S�5�+�`����o��/eT��^!|�u{[C���Y��	9�(����)�?�Ro<��F#����kn�QW�g���h�MG��os��P/�R�k��5����_a��H��C������N��B���_T���_���W�M�EA����SU4{�b����CK��'J�&"��%/N�+L0T����*��3
D_YgI�XIFYj��R��3�p��x@����T*u&/�Ju������^G���N�Q��F���{Hap3���Kfl����^g�����Wq��0 =:h�{[���N���5� �LH�Q�Sn�i�i :	��
�s�z��v�^��.�7I�X0B�����l�(�]�c�(��Y� n�����p���P�c]�����5���*:�wC���GVv��VW;[���q�������

j���m����5�p����E��+��Y��RQ���Rn��p��e���3d�@�����hJ�+��Y������!�>�����}�����W�_��������H����'&��Kn3�F>_$�m]Ne�g�xq�z�_Uae������E{)����p_k��or!�?�@y5M�<PZ� �p��i�z�_)[�l��l��GK1m
<�7������Z^M8�l�S,�c�ZV��19�>�L�r6�"�A��.�G.O��<��mk\�*�]�������vU�j��<�u��5�L���B�����%%�V����*"���`k�7�C��Pi��L�7E�,��J�
<0���rP���� 3v��`p4�\a����s���^f��ZA�?{��[�]����v�,���\�����VV~Y��y�r�G��~���Ya�`� p;�i����E|
m<���q�t6t$dL���$@	��z�K����k
V2e���4a�h�7��S�=������/��oo�?��cO����RVJ�6"!�A���RJa$h�����H���`
���
���h�eTD�(�"��;���&�*��������&��o4C��iCxw(p��j���x�j��T�RuMJ��������T?��\�U��b�7\����r��O���YxmV+vl
Qj���������
$���ZM��-��7f�]�GK�L�7������9��D�Gk0���8���G2#��������s�����9�������M������Z���,�GP9���=��!�c$�S�L"Rz���1u��s�i�0�}�az���\��R��3� �K��������RPN��D�
���\}�+��o�VM���:dC9��+��Hs��Zb%��Qm
;��p�u���eq����+�U&�F���
�)� /����!/m]E���jaco����Z��:�`��7$����Vm��0
����.�6a�����brIL(�����r��e�{	s�K�fLQ�R���UG#��P+�T5le��\]�������(_}���,�	�,<%���br�(q�	���N�Cn�,������*i��"�3���J�&^G��z��%'�y����6"�w�����&����P�r��&�C����Xj���JkML���q�X]4V%s�F�F�]���mR�6�1�$��������X���E}������L��������S���7�����i������\P��j����=��h��E����~{��~o�������&�}<���e���f�Y"��Mc�zo���X��Tl-s���#��+��L�.[Q�H�MlrKe|�o|�G:��R�_5��*�o�qb���7�a_9r�v`�}���;�/�U��I�N�r2�]���t���� aU�����R,L�������8��>��
4��tW�����P�Z0M%���;�vIx�82zB�(�)f�GQ�xy�&*ESh���eEH�Xo8�L�5Yh=`�j)Q��i�����|46�B�����,�4j�Jm_���ob�����:��Z��X��F��	p12�P����?���������-����!��W|�{���E����F��jt�NX�/��H[�$<��+"q��m��--���d�KH�`C�n#����Y@�����H��~��O�����8�M���`H�����3,S������UW��	�_��dgW��ZB��U���76TWM�@A+�����q�a|$	�@r���Y��*�?n�&?
�D����������t�����	/�����?*0GM�}v��1�=�;��&����I�����������D��w��Y�V�����$�_#�,����rm���;:���D��~��f���
8��4�BM����,Y�z��d�	X������1����Uj5������_a�7X5l6B\V�P"�1pp��l����V�k���GY0�0���:.q0��U�>uyG��j�?�������;|��6����63�v��>�|&���Y�����G��-�?#��|y1]'o�����KV����
�_��9�2�&��8*����,ft,�%�X�����%$�(b���c�����X��ka2��Qj&R���Q�'=�#�S�����
�����]V>���CD3��-L����^c�V�&%��0B�zWi$����vz�q�j`��BE"��������+��(� �q����t"����C�D���I�Z���g�Aw�u@d�����$ ������3�e�;����
q ���9�=�Y�c:gW���C��Mt2Ra����#)����d8H�d�F��\O8|����5����	�!��5`��m��R����eh�RWk��4j����t$�{CwBh��b#��j�-�7|���1�y��S4���6���C���U�DA����+x��n4������;`$!�8���m:w��V@l*R�f4��}ifP�3�Wq=�������>�d*�4Y�'�( ��J�/ZL�K+_�	�|��Z���.����(<d������['��C������]6���eM���z������.����P`�Ep��|d��7PB!�*I�0T�^`)��+NU
��]o�H+��)
� ��l[�l4�_7�7��<i�M����N��?~!��L���M������g�?W�x9��}��yMY�t�3�>8����������1@/�x	��nX	������/{
�B ���%%�,�p<Q��Kf���B}6��}��:�$��nA���S�����H}i���h���e��:��l�v��EB �[��H���{�,��,�=%Mj��Y��>x+Ee�����/���k�|����L�6����
q��J�#�b0n1Q�%�����x�Z�������C�AN�l/���O���c|U�K_�mD<���I��u��y�N<h;B����Z�����A���c�����6��?��?}wt�/��� �0���{~H�8��C�Y��2��n�rA�6��pv&;��d�K,�	��8�5�"F������@.cYB1Zh!��0���SX��X���v��lu�������<P.�6y1�;`%�?�x���
��]��Q��������l�;��b-���|'��P����Z����(
f�@xF4���1�6Zn�D��u����(o���F���7��$�o������_u9�#ZL����+T`�G���<Tl_��������P�v���f����'���r+[RB�	�@nC��l %aI���r��l:@��o�'�:��S.D��c��%Ky�^C|����-i,�
�T��S?��[������T+�q{��0�����WH?e{��AAU�*���0�5������3������H'��cH*�rF0VXa�A�/�U���"w���6���m0/D8�uM�];[5L����w�p��a]o����!�r4;V�}�z��I�N�B���5-"�j�Q�o�����*���_���<k��&WK*�;���������EU������Y"�+T&�������	���l�f��oF���9��,���|��s�'���������M,e
�#�����W�+�����������^=�/#��"+}�������T�s�sSjOZ�������XY��B-,:�����Jk����.��.pY#���f�wB@�_o�'��DaG��JL�u�u('���c+2z��8������_�u��%- ���su	{�%�eH�f|VN�����;^��{��y|����/(�y����0&2����^���p�^T����3"�"?R�H��_V���?voO��z��X����w�:�����)J���pX��'���&��$�8�L,Qvf�mi�i�(�qW���>��C����������45>��Z;�����*!��v(��j:8���@���\]����F�I���i�t��L�rQ>
�x�5V��]�D:dH !�LEs@qzV9W���J�"|Rp�o�Aj��/�u_��@�':���Z~6���lD�q.4���j�����D���Ni���*7��|f����4MP�����~@�A��4��t��V���}�K���(��0�5{u����
�Y�q�A*�u���Q��2�3mv�	8���Qo<,E�q$j1\�����rU�~
O��������u:�����%�H���`��?�Y�F����T���2`4�����j�Zv��_�w*�Z�@ x��BP���@c�9\{�+-�2vd2��T�y+[��7�p��
�'q(��^�fhikJi�T�B'�����og!�S�DjpI%T��>���W������z�V��r��,{F���`V�����S�}���h�2ya���V�zT>a�:�/>i��*�
���9X��������(�eR��0�17M��dS��s��!%��M<
�C(�Y
!�X:�%�;g�">��N���]��#�-������@����$ �I��	�r��X]��6�=�Y8z���Y$S����Q��9]V|����b�A�-�t0w��K��%����yl��N�~#�x���4��#���%n��3��;������&��_�%=���3)/FW
���U[d��H@rgL��d:
`��t��\���1��������I%eC�^��=>l��@����8�Y����E�����Z��(L��NH���$4D��F�az=t�.����$p��2�|�bn�`�T���G~�N�T�����E���s�� �_7�=i��B�Y��\��r?!!�%��MI�>w��������G����l���k�^�~�E�
����AUmDi}fsg�<�����fB��#�\����
@��~<+f������8r���W��+�z�YA�~�[��Qc��@��RiC��E���
���H��
��_�!Ub����Y��^q`��z��m�<��r����t�/��L
L���P~	�,\}q���|M��������Z�=c������Tdq2�(�	������h�|��C�sk�e���5{������w�����T�|r��y�p�h\�cta�78W�Z���^f���(fF�_nM��x�QM������H�F�\�i����2B�.�Y�����x`���U��H�lZw�k��*�`e9��8�J(I�=t���]���T�j��D��W�T
�h�}i�mK�*��Q�:���w�s�2l��f���.�����*?��C��������nN5r�UJObSg�|E��p��7��Sv��"�E�M����&c�����d�J�g_�_�V����k�):Z��5����`"zLs�����h<O��-�F���{2f�O�y#K)�}_������'���j��X�2���C�E��p�1ZJ���@L~,���h�]'hx���#4�653^���e���QPy�����P�he1��DrG���b���%R�&�w�VFnt,){�nu�7�v�Kcub4���L2�������eT�&uAr�9�0M��j,�1D����=�����y����[%��-�"CH�NX�����a`��)�_��$��of�� ��J�TWE�:8��d����n�x2z,��}�y��m�NK������BM�	�>�4)��-������%r����+�/��F��#	����;�ToJf
��`�=5��5{��P�B^r��
0(�������_����NT��7R����_
�Xp0����r$������QH�O�Vz`8j���1������26m�����B�,�Y8_`�:_@��������[�}����P�L����Z�Db�d��'4~u��
 ��%��R���"n�p����@��S��BFG\�5�����`@BW�u`�m}�$mP�C4+z�x��mG���W5�O8��c���KL�8����_�+{80�����qA���#�U�h]%�%��g��gsm��!�'_*�T:e��ZK�+��~*�YQ�q����VG���FjX���������b��3Qq�&�#O�a��fZV[������������`!
�?�5^O���������J����Ey�1b�:��g��0+��]�l�B��0�M���=�����������Il�'���e�e�%�x*�8#ZY���Fz3.�w�kuu����>;���o`3���/$p&CA
����	.�����"�Cl@�K�FD��x��%p���Qy
(N��%d0��=a����i	�|?
3�Ly~��*Z�����#��u�������K�_XX��ef7�h��A���*��eU��9�l���t��OdM�p��1p��m{G�i�i`�����(�Q���9�e�L\����>w<������
��C)�A`q�$��-�D������T<�<|$����#v}{
�ZF��E�y��F=��@���'FQ|0��SoH�3���!�`H���\�\����	~/V;l(�$%���A�\Yt���N:]1���#q�G{���5*�i�<4(j
6�{�>Ft�x��z�D]y=��M��&���5R}%g����#�da@6�6)I6��.h��i?����v����a=qX�d�b����V�;y�42=�
�=�B#�ENn�<z���r�IQO=-S�������,���_�F�XK�9G�j�S2H����ma��X�+bi����6
���LQ��`
H)��ez���HsJ�	Wa�=�*x�&����R�J��l�;	��A:���*��>�b���������-���_
;�g�&� ��'vE��.
f���&|�g�\�_,��<J����1B���V��
,`A�3x3�4���\lCb_f�Q3o�v��Po_U%P#p%�"SB��E���
J�$�o����9U��Z�cm8=�(�Qt�.�Iy����2�7��P�j�EO�A��B8]��s���Y�T�|f�o'�8��?ht�d_���JH,�'�q��I�y0����}:?�(�0B�g����7��H��?I�=������W��i�O���!B�s���\��4�}�r5�Bz���}:�A���Hicz9��[�R-j)���45�5v��������_�C�t9�)���i@���m���@�0n�f�c�5w���sn�f�o�S��F��g� ���E��.`#��?p�NSX�d����*��8�|�O���I���*���`�Ix�"�>���,�$Y+��X��mT�{�"KQe��-���"�,&��37�	� Qd(i�0�{��?��Te��^%�L�r5�������.u��U
�0i)�hX�H_�&�)�7�����&/l�����p�dE��&_V�k'IyA�G�;���j�k�|A������m�28���-����]6�@��h\^6/Z�������]?����c1���l��B�\�����f��i��S�z��u�x�����/��e�p�cov4�.�4�x}�Ikc�_��S��}��M�r�pUl#<3!m61����n�q�yc)��|�#�0��Q�
�[}�Z�E�X��c���n�9���G�.����(����e�5��P�!���F�uw��lGk��)����E�d��$��o�l�*��j:u`���8�����h����*p�lt�2�����Y�3	���@����#VIY�YI���\�Q��Hg��_���*��$K�_�������y>���w�M�����Ap{����#i����n��G$�&;���n7][����lnv��������U{zx���R�H�j`4x�[����.(���14BeI
9H�*��)���Ah�����y�}���y!����B�a�$��������+��Un��UU7��,{b�`�2���Z����`,�
^v����������	j_L�UG��������H����~�}N�$��y��{��j=\��mf- ��$K�h��R0;�0O������0&�'�X�����"��Lg ������*+[����;��^p�%B�6�������WU%��6�MXi�w8����i�:�ZD$���o���5����e$�SSe`�)P����r���Y��52�A�J�~��[���A�yv|�B�q�~��#�Z�oC��ib��K�~�{<��l�3�nN������H]X��I�����L+�&�W�lp�io�~4��R�8
��E��_Jb���}��jpb���G��G� (	v��[�omP�z}s�VoP�E���d�)x
��PW����\I��:	�HV���z�=?l��S'�,qT���A0��@�D3�3I�����Mv-]B��duy�}�)��������4[d���9�J*�c���?t(F|�C0R�E��0�4&gq99rN;Oj�l������42��5�uB�t	����+Z���zM���*�2��Q�9�a�p��
7PA}X`<S������XE���	x��~7g�eeA9e���8�^&��p�38��y�fG�l�bU����y�WW^��|��o�����3����9�\e'A�KM�P�������
���f����P-�U6,
�9����!���f�,���S����p���6��f8Q�r f��4��M������SB��
8��E�����D^&O����U�����>����	��h�o���{�e8s�`��{��}�G��I�<���)zO��@(�A6�������C�����e�5uU���p��R�
ZA	2�.�T�N���3�
�f�fS@�o4��2��\_���f�d�]Q��[�@H��"�8�2���C���L�Bn������b>%�b���Q��1T^�*��4�����r9pM^%�F�L�al��N0]�&��B!�|<��j0�����u���G!���8��b>S���l�w	��v�kQ�h����}��H0�-BI��U�)��+k, ����'������hK�5��^���8g��	
'��#���2�h�n0���y<�$��S���#�0�g���U���Xc{e��PO����j����J�HZZo��B9#hn�P��c�\�4�aS�R����Cd
��w7k�m\�����^���6��8s�Xy"/'������>�	�a~jM;t���o�������%�3�&+p2�$����+K�Jw#7��f�A�������t��������������^��D_��L�X����O)E4&�:O��i))�)7Q!�P7�����M����L�'�|�r%��^���#G7I�T�%�^��)�����G%�*��Y�C��I3�r�#;y��S��L�x���9,���P��PD��'wV�E�����<g����9NNa��������I�&U2;p�����T�9�s�wK'a����=�ol��"<1������$��M>�SuF�O���{�I�ed�����o�����E��&�/!��%��9B]cS���^�7�����$���o^*yK��h*�,7I�\�8�}����-���1��(�|}s}��2_�Rl�d��������4�}�T��v�9�{$���5�|}k���l���Sg���G��"�����x�&�%#��b���:��'��4}�u�R�?�j���Fe	�U������{O9��vCA�IO�e0��6i��4�m�?�dI6p�����-�f	����K��84/��"#?��FH����H}4�^w�fk(s�h�=�<��$�����G�wo)i-�g�����k8��@�������7�W�}Z�W�=@*�C$��B=�k���jt��U��U�j0����]�mk�E������9��6��`�M��Y�(�
���l�"ad�E��R����[�l���D�Qe'm���`�����i�U@J"{|��=k*�B�'f�U�.���<�W'Zv������E���|CQ:��#**�=����$�����t46��gh���7�
B�Y����l� �%�����\U���o�U[�\��D�4vh����[w��E4�������{ ��#�]bY�\��nFC���(�3nFe����
�M��o���:��If�DU�k�S�G5z�l[3�K�uV��7d6��U����A����{��������'�o�l��G6���SI������&u�e����Y�%���|�L%�~'q�9q�p�������X�����EWf!�(����r�6#����#4��N���C}��:�W�������/��blw����F����9�X�s�6�a�A?Y]��[����j��Jd@�j��A��B..&K�p(SN�6�-���u���TD�6�?�����#4�C�IJV�:
h����v����.$M���y���y�h���������>�������������u$w4*7��C�	�����s��� K������d�wu#����q��v>����,���WYQ�n6�!GJv �����
t��d����3�-�H��(�2��A~��b��3J����K��r������E���r^d\h8��9wo-�+�=
gF?���V'�Z���3HY�����{W�DbAn:�@ABN,�eF�&�A�{�3���m�H@H.���|A����]�w��;O�vY��d��e�9�e�)���4�2�~#���*x^�'�i�z�@�m��^�e���?�ax��X�%���w6a_���x�s$	U�]�8�����hwE�)�N���E>�RH+w�;{�kk����f�[��R5S�]�
"���������G���O�(f	3o~�#���eRy;U�v>�u<F�I�';�r�����W��?����	��ZN�:_R$��R�0�v0"`�?�Qh�WWp8�K�9|LC�&+cv	�eW���=]sL*Kx��o���C���jB���jQD�.�a:�Kik	�\W��7)���i�O��6���m:����n����lm���(,�#�oM��|�PQ�$���������i���"��)0������CKM��]��U�#rX=��QQ��g���XC�c*�\]{����W���5
;��;��z>}���u��/�������pj��`t�^i���b���	�.��A�y��������f��Yg?]�"h�8�PIE�G��ZOK!��2/e<^�~�������M���������������Z��n_��X3�������O	]�h@'\�#�������I�.5v�%�!C��������Xj�>�}������
����<x��QUiS�d��]���w����?�xs��
����pbf��Pq�^O��K�`/��lZYI�+��8Wh���"Lw���
U�S��y�i����aGNt�������������T��U� V�t����p�~���ep|�,	��P1�yS�@1��/��pO������c�
A,Z��:���(�*���dC�j0����	�T�i�z0i��8	J;.�:����oG���"�7�F��P�����/<�KekaS84S�'G�����B�m�hY������d���_)�{L��]���i��g8��R���a�i�!e�s�?�A�d�DFK0�����N��b�M�q�)��h�]����d��t#������]N�"���R����h�+FCn��U�/N(A�Y�k�_�+j	(��ev���pd�IP�1?<�`�Jh>�
R#�,��6�����v���a�]�V��,Di6�"���z���L��8�m'��U�'Feb�7��4�bZU��Pk����(��l�VL�����x�6�����C����2���$@}�IG�G�m�U��{�J��
��G�8S��2lz�
�����$&P^{4�i���K����D�kI��Z��.��������	��S�]6�
fVR���X���������Fgc}m����o�WeU��"��*G2��������dL��6����6��W������'F���5�[�kGp(��[�0���A���8������}j�����������6�\��LV@���q_�u@y�<�uz�x6"���<�r|��t�������z�U���`e �����{Q�QC���g�g�G����b�����2�u��d���i��60�u�J����.���XiA[�����������8QqH���o�WS��*����*�$�	F8��fF�Fv�aq<�U��Lx9��R@�f�[:w�X��^aJ�=@�`��6�NP
L1��@����s����}�����J=a�:�T��Mw�������?��%QZFuB%����t:�0�%�����S�� M��kj���KXq��
����<�����J��n��9^Po��<J�7���WB;�7 ��|�H�$��t����j."�:����a����^o�^�TK#E�Z�!�������Xg�`����d������
����')��x
�w��R�	�gD/�9��}Q����S
�%��E���"Lr��W:�t�i�+^��}����	7p���Z&D�j�U�PhL,A���7P�l�LW�y{f���
�x�^3�:%0�nzm��g�7��|T��"i�S�tg��`B�Je��,���o���[���2o���x8x?2�9�=`�*W���tz�^N:���x��R�I]M��\�,wYx�����_j�T������.n�����3�����%��ZQp�d�Y�v#x��4�����w����k"'�P�G9���h8h�
��!���T���I���h�����t=9{��p(N�����7�`$6��q�~�yb��Wh��zaX�5(��U�[���"��%�J�+b(9]�c��"�������������/yi}���+�k����]��&�?;�������Y���z��*���/��3O9e�+5j�����9E�&+:2�������9(R�����Ib)�I�}�G�	�:QFz&O���D�b/O�c:�����HcJ�{�oM|>���]�h��N���[k�<��a��H�����49����\�$S�;dE1zj"�D���c���0+F+j!N�����e��u�T�Vj*����<c������8f�'�s��.<9���-~pV�Q���'AO��Z!m�\�5A��������u������B��'+�Y�=���8�x��\
p��Y���0���H���)���Vl�^i������d�x���f�����3m'�7:
"�I��M�F;Z<$	�*�0ypo4�����p��U���d�K�>�_xo���F�>�����0��������|D��j82(�[R����8��<���;��Hix��G���+\�q��;YA��SG�t
��IRFWX46[���u]I��*bBd'^$����DM�LR���u����t���%�����<e�~8������k�d:R�RnV��^*��Y���e�J�/ZQ3���4�\�����t��B���bm6h�v�XB�0���i�}���6������'�4���T�Y����xu�,7a�f=]������+�e@����6,����5�9g=�[���,�����JiB�-��J\+,��Z����l���Q	m��A7��������A��!+�������D����Q�z�Z������&O���t1�l�n\�*�{�)��7ho�����`�N����N2	�,�X�^-�[���Z�P+H�,���&��'s��	����!�U��������g��$�k��hf&��s���W�j�	�����l"������-����P@��P!�d� @g��9���e��'�����Fh
�r}V
:*l
��
�Zxa�B��/�vk ��
&vU�>hC���`<��Tl, u�x��T�c�%������1�:�����r����:�a�`]�d�l�#m$K2��_����G��ZW��\���i������������N}wmm�����n,ru�Z*s���%Rc�.�(Vj��������|N���b%��3D+��*�%Z/_�41����m���/u�u3H�������������}u��v�r�o�?�W(�^V���`�Z�T��oX�)�w����9/"%T�*v�FNU��3U�?������ge�����8!N���\����/�G�,�Tsn����;�.�G���.��b�Y�g
�O����Lk��_n%�m�_V`Z��=�)B�����f�TK���C��u�)��}�q��V:C�� n������&X_%=��K�|��$?�h�?�)��s�SX��7h�6����w��d��~�q�����n�I�i�g�����+���S�R���� ~r�2`��w0M$��82�s��^#�~��*g��}����_�y��F�`��b  �B��
[��gJa��o"����x��"(��;����/��PC��Uc�|�o��R("q�)�]�����K7�K"�S�=f��"
��7�o��	�E}R�G{�d6�-��������_�u�����,!��<4s�i-�������&<�=8_u��:1kI!�]���"[Y�,�8LS��D��K?}n���m��L���{p1��/�*B�1S���t:�������!^�tU0�� q�
���
"����g��^VM�j�{?�*���	�t,KN��o�/��6��v���;�F���k[~�J���6��'���f]��U�F����)|��U!�c������"q��������SIt�����}�������	n����O�[�6�2N�f�c2��"���=����?�d�t���IF�z�t��by��Cfx4�����a
x�G&�Cw������!�=�5"i��5�"�������M|�/
�9K��l0D6,���T�O��[7D�{�����;E����$��L��dsrF<}���/jr�-�-RI�&��Y���f���Bdz�a0�3\r��W�~3������D�.!IL�����
QCt��
3���\LETL����mB����S6�$A
k���f���ig��{����4��M.���t��I$�0Z�<�O2�x;�c�R����|�n��si�-^y	vW�#s��Z}�����w��%��z��cj���e��i��AY�{\�Q9N�G�!)��J8��������4�B7� �u��x�&*�	�#k9�@'�q�aj�%�z-�~5��5�*_�XN�.3���7��
����'���L���&�-&Z�NY>^��I�QW��ut���C0�Zy]�[Yo8�4M�]R���?e����R�\�������7�|Q!0Qfp�s����yb��$+?
~v�8p P����O�fE|��p;3M
��E�I�jV4�������?&"�&�B^+��[��WnZg�9���g�K���-�h��?Nw��!�I�D,��B��A��m*
�2(��;��0��0�a�L������*��)��`�e���{���v	0
%��w�E
��%6�����n�3J6�4��qI�B���������FK�������%�,�eg�]����6���!�j7�y�B�qO������
���<�N�"1�#���S[Z*9���,���8�S;�s�PI�!z�"��9�C)�|0��E�
��������������b���3��g��h<Es��w�"������\9��������gt.��M��^�v��/��� P>x��i��c]��`��*S=��4x�)<p��w4-�X����<��������?�F��h�.T"Bc}��������X�#�����1�������L�%�Kt��8�N�A��&?}��h�l`@�1���d�kz�V�����g�i�t���6�]'l����9u��Ux�y�N��T=�aS�E)����������_�D�AoG.��2T���G��s7�=���xS��#��z�%_����O�P��V�!t9�f"�}�9�5`G�1�9D�P:{*v��8�����kdXG�Ts���s=e�:������a�EvG���]�s��(N���s�o7���yD�����G{��
o�hz�Ia�?	������t�A���@g@���,��zhU���}�>��%oi���v��}v��#��,��/����1>�.c���eT���?��hP�m����/x:�v��dmr2�|1���M{�k564��P���X�Gx�e�$�K���_W�M��������kai�\
��e���z�u���1�?>F|���FT��L3`C�W� s��n\%�f���D���$^�4^�Lq�
�YW3�������kGTe$��4]�'\�VKv`���I���w��f���M|��%1�'�aWpXDl�Z�g��L���yR~��qo�4��Q$�T<����0�V!N�j�����})��zT�)B66V@=�%�*�����RW��N���Nh��MU��*?s�U���zY#�QW�Q �.�n}mt<�E�v���.���[����p�gE�8�������/u��D�6`��I�&�]O�,�rh���Q����d���p�V�|J����F��C�4s�2T��!��&����sN�3��Y`&QQ�I���wi)c�����s�L�U�#�2���{Jb��CGDN<�G`�������[Q�sB��o5�n�a�P�h������:����b%����0�N��j-]���t���.�Yh8Y	�svd�& �k�P�uK�[b�zn��A�w}���mc��,�
����l��������J|� ��3�d<�m�*���	�C%��~���h�� 9����=���?���j��L[������<I�--]PT�9c�N,H��Sy�A�����#	C��>XV�%�����qd`���I���3�}�T����k�����z�{8��o������O��,�2@L�����p���I�Y���+�{[�!�G��Iu���_p<�h���(����Y�Ma\�C��e���.��8m-P�0:)�*"^��.�]C;l���I���g
J��S�:�PL8�!E�]u�u<}�
.9O1�]�L�7�7����������������_�}���~���w-A���R1G9�9���|�f��M�����og����"�D`c��
+��q�z�$�)�A���>�%�lRK	�\����������w�F7��H8����)5�����@f�� �������|� ������7K�Qx����?HT:��!����$<���D�c���U{<�����c�:���YG>�"�P�j9�4V���m:��/���M�:W�k1�H#X)3�Xj+j^O4
�Q���Q��}�<���9��L�Q���A�����0��	D]�g����f�E&��.�b$xd��;����&�D�T"2�����M]�i�VQIN�m�S�����ng������V
%�
4��J
U�s�M�����'+���2p�\(��b��O�J���^���b#R��$��_���H����^��M��cL�h9������7�����|]���Z��8�p���L���\��u��p�W��yy����I��������.}X�Z�����R9���Y��J�o�"�����0�k�Q�	�J�L�����oO�- �p��
�>n5�B��xw|�<��JT�Tv%U���Nb�T�B��I)8��vm����Nmg�4�e��G��2��e��R���F�vy�+1��"f����|�2gxwG�t��.�kq�R!���_^�,1��hi��,�P���b��I�w��}�h+�I1��,����&�~K"E��p�&�q��fJm'D�#j����,�J���]���*���������Ebo�������~�?�����P��3��7����7������e����#��u_*"�jI$$~�M$����'f<���_�� 9��#��]�����R��p2z&�����K�W?'����pk\�VV_]�7~7H������]�r>��,].E%|.�b~T��Be$p,p/�������@QZx�O*:�70�I��"�����;*)}I��F��x�W����A,(���x�tN���r:q(]��~���(L�m�^�,8����
����E<���c���{N��=�jvohT4��%\� ��U�Y�|��Z}}� &_�4���S�QO��`@�v?������Sn9%�7j�m$7h�:��_���r�~Q7�$���hn]��k&/4���R92:D�^#(B@�����p�H�R�>6����7�bi�k/"M�L�.����s�w'pH�\��G�y��2��#
�\N����gj���,���Tf[��r���{)�V4���g�ms��1q1k�����o�07_�5K���f��t��pt�z��R�3F.J�<4.O�#����xs�R�x��jncq��3�������=�U���P����>����M%�Yz����x����h����6�r�/I����������{�2W��:��F��ld�����:G���w�����xVQtm��\]*�S�#�T�/d$8��a@�A$���:'�����-_S�%�|�Z�N{���i�����xs�t�x��4ncq��3����O��=���,�<c���A5�{�(�����@%�u�X�a�w�C+��r��}������|N:HE�}��i97&)��)��\�F�GI!����v�<f�=�=��;����w%L>�D�����} :?�0�I���ua�M8{��19sc�4�:r08�*�q�f!���6�=ByH��l��nU��,�g?__S��~�s��!�/Uj-���?Eg��9���(t�$�d�?���j��/U������K���Y!�W��JM�V^�=��Je�������>�p�8 ��%�	�����������5[g�-�o��_Bl�L1u��,���}/����K�3'(Y��S�"~���Q���0k��
�J�-f�m�Q�:Mr����8�������Y��b���rE��)iu�],w5�]����U��)���`��LA_B	�L��+D	��Ud������Xw0,����;|i
�Y��Yx�`�������zM%�3O��L�\��S�L�	oM��o�I���L�e����M��'O��9R�=c��+���2bsa�-��J>�4�+�40aU Y�
7.o���j���=_��.,�O��gR��\�����S��MVv7�����Cs�|�x$�(��mLh:��'WI�Mv��^fdwlY%�<MY���.�\���"q���X���M�������B�������k����
��|�M\{���]���@��Z�b��wo��{P��Y������9TB�'S!i)�SML��S�Of���47��V����rP~B�"s)�h�������\=�I�'����*�R�'�F�3*]
���ppr|�>?�8x�l5/���]�*��-�/c���l2Gfp���J�c�a�����g&�}�:�}�YSn�������c��������N�t`'��������E�V���59C|e)r��.���:^��t�c�#��LK$���,��}�#�s�P�E���x���P�C����%�K�N8�);T��m�'��<�}�������yC�39�*)��6���>v{�����U��J ��
���}6�c���.Z^%V�&2��
d���,��`�0��y���B)C5XG���x6�Q�����zm�A1��LR�H�����Q�k���\�q�~��
�h�V�j��2����h	Sb&�wv)���:g�zH&����`�������+o���}�M���x�GyU�L��.���A���fp��!���p�0<b@u��x�FdC�y���%(,Yec��,]�%�T�����$�3���-��^��@���\��X|IW$��d4�=?�$4��9i2h@|lJN$��C��g����h8�]|���tr����^���D��������T���������lon����Z}����bep�>�����r�c�� "Gp�����ay��?[�I�n����/a[#n��B��=��~bk&^9++����<�\s3F����4�����P$���������/���(3�u�u�����7[��1]�gB� RA���u�*Y-<��628�Q�"y@fM�b�!�|d�\������O����V������<r��d�������H�}	������+�T�]gF�j�k����,�^��
\��n�/e�����
�	I�xh
��L��h���k�u�{;[����a�:G��K��R�O���m�}
G��������j�#;.\M���-�1�m����=���p,�+��m���`��o&���v7I���ThK�.c-0����$E�5#q�3�m��������f�^��4��*k�(�!e^�!6�9�d�z$����&~j`���r�:�����|x����\��3����}��p�5����&�I(�)��.�[�YJG/�OI�����Z]�S3�Ui�-��;��u��v���P��E
d�����
?�W����{�7�p>�G++*��bA�����_�5m�V��*��/j��������u��r�UJ��[	s9���I)&���/�T)�(�x������L���U?�)�(_1���M5��y���K���t���b��Boo$����j���X�
:{m+T���:FH}�W��O5\D�h��0�R��j�������hzf�*|��B�ps�����Y��������tf�a!zi~=����	Qg$j�%k�ay�|-�{����#���w"Z���x�����?�h���$?YE=�`�@J���<a�%/�Ig8�*r����e	K�2<W�
�U�o���0PL�}�����~)����>LA��/��}�-3��i�v������?�[f�f+���M�D:����N����eE��J�5�l+F"t��]<C7������\S~���r ���g��:���{9$����@���H��_�S���ui AH�U@U��EZ��� �K�����:'��&4����u�,�MB�X�q]�������E�s��.+��Z��9b�#
w��=����E��K<���t�G/x��Ug��KUj�r+�.�ER�eZ��C�f4_���t��l������z�,����7������Z��#e����$/��h�J���6��]��'�D<�6���������c��n����#�;���@��&|1�A�U���|K�g�Z4���)��<a�oow���
��[��q"����o���[
,�p��@��u��������kX�'�8
X-�8���\4�SmV#��)���hW	��UD���>�G�R��S�J�%����$
n��-eX*O��i��������k��p����z������p�Uv�6��%f�:�`a�UBXF�..����LC���w���H�����=��G����M�
Am�NiiI1�b2��>t5i��O�+*�""�aF"���	�2_=�B�����O��(�t���������F�!�Q�kQ@E��T=J�f�����3����B{<�s�
��&(���'���M������<;�xfGf2(���R�����C�����J���Bf���_f�A:��N�����ic�/���j_���Z���G�xE���h�jf���K����$��0Pev�������������Q���\��)f��W���&������L&��Hv�i��r��(kGl��Q����,��dU��z��10�P!MPP�2DDF�%��y�?�,q�� g��.�^o�ku<rl�7��C"��%Y�s��l���}�`cskY����L�xs�G+y�1��*�f���9�!�%!&Q���2�`���r�"�'��+�V�6C��r�%��"j&�c�L�	�7t�� e��!K��C�
?�V�������p��{�#�:Jy�,�fle����=���x�o�7���r�����4c}�e��g��O&#~g^��[t6k���iL����������#����0 �b�W��y1�P���|��S(b��V�`����~m��}���.S��!�������X�������`_���	4_5AD�(:i�S�E���=�|!�e��H�������c���pUl[4CH*	r9@|p�����g� H��)�0k�3�EF���O�'b"���-G��V�k4>f�`�|Z��e��H<��b*l@���1)0���=���b'������F���b�S%��)���:a�X+(%�,��<�@+C\�RzP
�$��4�Z���u��o�s����g�D
O�-�!/��>���������;F3iM]��0
�d�
H/����r����veEBH?O�wd��H�3A/�X�=��W�Gg����b��Z���r�08�)8���
��^�oo����H�6� �v��)��2��d��PgR��q��<���%�����u���.��d������Cb�1�L���U�j�x�Ge����c's��s�3�T�����5h�������s�B���a���x�'*�h����.�Q���"���\>����N�9����������k� ���,a{������T-q]��@Iz\�'~��}h���%��g�'y�\��Lg�����K����1��=��������b�SP�u��'�r�D����>:;m���+�VV�#���j������
�.������������ca��H	�{���w�d���G�e���o=�������K	����0s����}���ik��~{��V-�B��o��z�*����n1��$��o7D}E4�zY%����[�28B�5n�Oj]�x\�yfsc������M��g)c���d)�w��#�uP~b����bJ|����y�T^2&51���
�.����	���\A����sn���j��)�/d^��@WPQ�f4	����w�������Kw��]Z(���t{�{�}*"��4��T?�dB������"������`cU����/p��*G�����y-0A���$|W�$����Z63�����p�M�w�8o=!~��y���<Vi}O� �ct��|~��u�|8+���P�V5�
o*���/S��h�_�5e�F����<,�O��6����n��d��*�d�t0�?\7�;�I-����F���B����{<��ML��'`d�c����0�b5�"6�d6��5r�g%.b����
I�k����[�[�p����zV��q��^���P�&���{�Z2�>��+NUu��MU
�U���X��@�D����~�\��e�O��{T7�u���V�Z�����d�k��������dI���:AW������x�P���.�	N:M��/�C����Ur���#F}a���i]�������Ic����[u���.'�D�&�d���{�(I=����(xi��4��(�����az�
Lr�bg��c��z%���@[>�d���Cm�S���V)��r���o}�w0?����e�i�K9�v��#����/�����b��<�����O����2���:��t�M���:C�2)��"*F�%��q`E���7�����H�3A��[��V[�@�����q����
Ud�U�!&M�9u���EF]���-���a���$�A�B��lV�}7�u4�4�'3n�4��1�q�J�:AS��W��y|�^��'���z/�B�[
Z�h�1@�<��������j�+f��f�!`���<X�-}�0����D���a�����������s)�j�	����1"(���'�_��T4*��}@'{�Y����K;9�3�������-(�@� ������c���%���A�9n��q�N���|\q|���e�a�*i�,���vo|=�3u�3��e���j��G�R���C��v*������g1����2�Kb�Xp�%G�7�NZ�������zv|�c��6/�f�w�V��-�^����0pl�-Y���^�>����,�q,S'�������X��lm�|�X��v�������?���r%2�%����(�7�	}���\�=�x�:T�8�#d�h5nS]lOM��FN���Y+w�d�����(wvv���Xv������y���uz�
].@^��?����C�VU[?JL�!��%�{V*��������f�j����������Df�3�����	��7���9��'����f��[�+)���
C�%�"*|�V�Y����&�k}ww�V���y�M��`��X���YYWa����#�f��(x��%��D�3P�pU�����c)_�e0$���>�Rc#�Ec�qG5iL'
/����<C��^c�d�F��$-�>�B��-+m�K�66����"lFq�Y'^�M����C����A��-`��l��c�|��*��f0�s�-���g{N���2n��E���V�Q����_5��$������\��?:�#{�C'��g����3
�opo����
�#�%�a	}/����/�iDG��h���/i.�{�����������^�H�^C�k%&���H�����gv�v��5����Pd4��d��#1K�����zBQ+����R��U�"KV��?�&Vh��ml�	x2�U���)B�T�_N�c��]]}�8a�(�6�";\�d�e�:����#9>mmo��^�*�u�OI}\����^�"���+��G�1�7�Qi���*����L3��(�S�?/��D����z�X�Q���i�C���W,KB�_�~/��e��Z�$�!�C�8K���~ �t�;���h<3��g�H�>�K�/�H Y`����-)N��k�h�Dd��WG�������C���0�:P�(����\���]8�V�T����������i��dV�*���+g_�c��R�K�]X�1������A���%e���;-���
H���}]�O�B��ATK������H���Q��j�Ss�:*�37���
(�YJl�CY�`�r �O�34���2��^'`h�*Ig>��6��������g8���kb��6�3�meeE�6����@2������]���"�JS\�4��������x[��dIg����F���-Q	���U����5���=$b��&��vUB+1�	6�p�W�I��!�L�X��kWt����wY��;.����D�@�(�!'(���5������sO������N��9.RB����u������O�y�Cb9	jyAB,x�LnRW�;��
��N��i�D�E����^����p�\�vO�D����H���<�� ���+�Y����,�38�Nt|*TapxvX8kt����s��lMV����~���t@�`w��cF��	X�����c����	��#���M���L�b��+��l$fBB���Uv;��r�`�1���} I����,vJ�����&2�����.���o��S=����J�"|6�-�K��h������a*=`�r�u��'+1���'�i�<;���c�:T�k59+���%B���*�U��W�D����?����=&u��tqJ:��-]��C�bM�n	�3��e�D�w
-��ILBMdtd�N��o�O�J��*�	��Q�E�#B�J5�+���"2F�*<I"�s��J�M�ZbW��(��@�G+yYv+&)����+V��I@��EI���nkq8k�9
[��������8U�F>�6����UC�VLr]Y�q��i�~=�5Td���E�9�eU�+�Pr���r�X^QS�L,���$yJ��z�"Y�g�&F��N�����$T�w T�HY���yFh�4;����	_q	�����(��e%��=c�����2�����s���g����m,�3u�(�U�dW���b�����r��&�����%�����QU`�A���XGr�D����6�Z2�o�%���%�.�xF�&�@:�4�02-�@m;���C+&��|5����Q_zf�n������d�C����Kp�\�LpQ#��� L����������toS�<�0��>����� �g��B7�v����0*�&�T��E��J�7��m�I�-����=#6��7�7[o� 4��#���y����<��6~9��*�(���6s�����=��f���2���7_3JXn��6{��=��=Vj��*:x���o������I~!��`�x�hy1�"���"��VC�OP�Dr8��f�0�	{�&=qS���Q���g����L[���e+�#����.n�X���k���5�gj�M�d���
L#���JF4�G�JY��U�`��]`Xu������b��U���qr�����o��,�A���I�+���x�4��]F��U(�
�������2������V�rP�~{m$�|bukQdX�H�?��`��Us����^Y���/D5�6�m(��K6uQ�K^4Au~��Bl���<�*�j�4�4�;��}N��>�"�`�����Mg8�aC8nL��JFPy��#��h����	��P�����l�����f�BX�����)����Q��u�^�=1������������a��gg��G�%��l�F@1jijW�������l`Z�D��x���L��"������Blq�j�i�/$-�������E��b�)iw�S�Q���n�2�br=1�an7���w�v#�<��,k�:#�a� �����eG��w���^9����JDN"=��P��T
S�}-�(J1��E�����&Z�4������C>��v|H�VNL\�!B(��x�5�P'��r6��V-f�1��C�������Y��l^u���!����X�)�#M8�jbb-�Yiv�������������^x�
��R������15��/L
���.Z�����GR��z��3�]U�=�1;��m��&Ix=�$��2��,B�����iK'�������U|+�G�V8'P��,���!T^�>�S|O�G�E%(!�q���]u#�������HP��@�W�Vt�9r�p~�<�1�LV�UF}�}4I����+���utR�[�)�a6T�I�����Q������{��PkLT���P���e�7W8��q�v*r�c�V���0^�M�X�����8��r��wYl�x�o�=C�Q��iK��$�|���W<�A���|�=������}MN���g�G/�d��(P-�[�Z�oC������f����G�������x�:x{�@	��sj#:�J�	�2����7~?��
$�*'�ihi���������V��B7�Tjc8;���C���R�z��R����=�����=����.�b�f\9<v�^<v%�cW�x�h�ls�c�����.���.����E]�j���w�//��[��,>6*���z��&D����qC�Q#�t�����n����}�b�p��L~�Z�V�5��oZ)�|�g�U����\��������nm�!�!%�����5����.p�)^?�%Rs3�J��*�c5��uM�A�w����������-��"NZsuDHY_���[aI2�����x��W!�D��w��#��v[5}����V����L?�ODNv��������y��Ca$��Kl�}����Ej��(�����W��I�_}5�D����)-�E#���'���%e�h_w~M^�D%���}a:�7���[�K�o���2� ��� ��.X6W����������������� �U3"�����[���$.���-:�s&!v��ov�d��i��"[���?3�f��7�.��uzU�S������$�i�W���p����� ����!�=@�q�����{����a�O��*���Q_���_�m�������mO��cq,���\��4)��D���O���Qd��������5���1L�\�mG�\����`�Y�[d_���&�Z��C-S�`W���F%�{kI�A�����4��{��oC�-4
�KVv�+�����U�IP�bt�!�]2��0�������Q;Y.����&'�������+@e���%F�+�z\�!��6e2�����)Xf�
����i�����M�����������rs!y�^�kWL.������|:	[���!���6���,DyG��vI�d���P=$��W/<��)[TmJ*��?Ub�]",N@'a��m���3>��(����%��9Z�aa����""n��5��\p��g^)]QI����a@�zy�Q�)'�B����\{'
���SA��n�K�K�K�`3�����������p�o(V�>=�������M�"�Er����Q�@�N��{��R����@�J)�$����(X�����
��	~��0H"��U��4�y�������rv;���3�/������d�&U��Y��LvMV����}=���F��,����&�qm+��)��N�Pr��E�^?�A���,EM����n��|L���zm\��ZXc�t���V%�TxG��������|���P<�t�w�F�,��0N�;�k�Cq,��R�F����R�\�j�H!�t���[c����0<�?p'�7Sv������<?�n(���c pP����%�w�b��������Kx���!���	��^��d��}��EXX��Y4$�"~�a������o���&��S���GW��
+��7\�D��]>�[���b���������1�gp��$������,����V2��!o��Y���`�������bB�e2�L�r�(����>��i<������U!��
�)XsR�K:v�|�Ft����V�k�
/1���C<��9_'0�M�����xi$�r��8��$E���8�#9O�����l�s/Lb�HJL�-��Q���_h
i�?�����������h����q��j�TL���:�pjV���+� aN�*�@��r�n�����[e���ohd�3�k���u0d��9{�`TH:�H��������/U�=
��������]�H_����8����8@�Fk���{K�Xf���b;�%5��?9p��D��J�)������`FI�z�U�B]�o��Z������D�ab5"&��&���!����;]S�Y�a������/4�^\�*�	��=�'�t�}�3��/y��Q����o6�|5�hM�3D���~�$�L��
Z�L�d�T{��g0=�e�$�|H/LN:�/��
&�hxZ#[>�(J_��l0T�-��
`�<�����g+v\(t�[&�L����=�.[E3d���)��uq�\��Z;i�U����Ef����B7YEcY����J�D�9��c��'�hN>t��������;O9%��?�,C�WX�C��9���O�6�F��'�74��"�QZY�C���uKy����m��4j����N��Q��.����5���l�����]?oX�5��C���r(��kTz�����ck�s��\S`�*r���<?+�I�^�6)���<�c�s -CVL,
~P��2���>56b�s��YfN�+w�O?�R�;^��u.���2��7�����9�b��"+�&U�����{��*�z9�K������K���R�(oa�2�RA�q&�G'b�n�@u�z2*�~N)/�~^97�~���/7i���;���R�����6|:�l<
U�q�E2i!X�Ip��V��'<�8���n�j����g����C�V�����2��?3��i�z_�(�&jI�D=��[�v!���V�<��1��d((}�9��m$+aX"`�-�c���� z�$	��>S���	���:�#'���rp2��IA<�-��q��&����� I-��"����Z)�����2��f�����]6��o�.������e����gs%K��8C�0><q���p��=������R�xPe�0��xJ���Zk�hT>n��M�*Lw���SU�e\R{`��G�����?�O%�w�
�N�N��1���]SA%V1R�g�J[�������R��1I���#{�O�\�:����:��Cm_���|;����^|��>S��jd�w����`���\�H��zV�g�$��A|V�z�B��=�h�[��U��[��o3Q��,-:
�}2����w�����C�+�lL���<�dy���>Y�,���x��.������y���|<���	�a:J��u43���DS��m6��lp�J�����Zi��twb�&�P<����{�\�fJ�{�,�^��'1n��y1vC5��o�Q��n�r.t�c]�/�mt��-����E5���m!�?BM(6c	j"*@$�.gQ&��
�2�����[��UX^8�
�l�|�b%���UIA^��"��7���K����'��qE;<89�h_4�����y�'�O n���g����G��37��2W(s�6�T��3����� d�����D{�f�@���	*����neSK���6/���9�j�V{�{���%����i��=I|�������,������-������{��j8���uu�9QW�f�j��R��.�;�v..�����?�����6�I��������#
���s���dm"R�6�t������������?%��:����������<��:Y��nh�����*$@$HQN�'��X��v(
�B��_&(�|}>vO^s�]��xU]��&�D�����F�]� �}����g1#�T*F�����k)���6!��AYqF�S�YKr�x�p���zR|Zq�
>�1�x�g���2�4a�ttw��+3
��*�3����i��8;��=��p_:dq('�)�N���c������\my�O��W��Q|�o��<����x)8��C�l��gx�*��\T���	������yI
���Q����:I��a��_,9J��O����h�P��n.��Ho��hX��F5�53���I���L����9�Z.ES�$��=�Iu��)���x.v1��'k.�R������9e����9�ZC� ���^����d:�=�0�����f6N�x��Q��r�]5(Mv��x��{��\m4Z]�ozq���v�Q�^����Z�Zc���
`�����	��q�k��mo��?�/��R!p�kA0O|"��[���q��o�>_Z:>8�7�s|��C����;���G��7�?���O�u~�=����������~DT0�/:��4���pw��2��j�w������Rc��l���J�����`�?t��
��������a�z2���>l���b
k" �j��7�k��|	������A[�ZX�_�y�D�Z �J�/!x��q���;yW>�����5�IY��Nq������]W��H���'�A`cn���P��<$���F�S(aKevkS|��j��pP�]S���H�k'F-S�5�q!oI�,�u���Yy���K�8�n����l7kk���o�����,o��1��a�GU�0@o\R
������E�:����pC��9������_M��d��[����
�e���5tp���S����C�W��ro�
�2���o�7j�����M�.4<7�
��m�H��C��W&��
�d�/}�_V�L1U���a,�$����v�>���xo@���>q��j���I_*����1"�;�y��0}�c������t��Fc��Zm�/2�������W�P�����������7����t�}B���oKr����2�H#�Ia���z�������.0`�}DJ���qr���\����=���w�S[��W��������ii��vO/NG�����������j�O��v��G�J
}G
G-���������{����7SZ�KF�V�����Z5�Z|x1���5�<�?X��r���+��+����������!�/�����;�B0���>��-�t��G6����on��������b�S�5�<���/�U)���:�>�ip1�'SAA�D�����XvKn�����C�`��=����&�~o��9�����?}|�8=9=;�xzZ>��~:����N��~s������9���l��O��O���Co���$T@.� �,)�i3NJ�Z���"���E�^fA�8R:Q����2�)�A�#
�������F���N������B����gp0���s�
�Y^��K���X�I<W4�uVb���f}�r����pt�(��:��g���+H������ ��}(�HD�p��N����WX��vm}�T7�kk��;�����`�tzz�~����5�_��UG���}�����c���|z�o������;��v){I����Z�V�#H�9�@��),������{Lm��!���{�~��>�'��?m���9����`��.�:-U���M��f�`����s������w���i�'|$T[��]Y>�.W���"�Y���T1���/��/�/��s�#3���(�<<1�O��s�33���,�<���������
d�s��������@fDt�?���d��Wz�R�Q���+'P�������c��C'��L�E%-�f����B�
�&�W�7���^*�C�����0�:�pq�������i�$	�'w2�@�/G�����a�"��q1�L�03��S���	�%�&�Y�Ge=������D���N������'7,*U��z��V����O��k)���
�Z����A��X��.@q@���7}[�H	��j�s��"�`H�e�uf!�!y��A� Yy2������$�Vi?��losY�7�a���f�h��MYz�e��!i���Wfr�2i~�X���$�9yeE�],��������(�Lu����1��0c����\���0-By{��y��t&��+�O U���q]s}
�5��>�s ��@>���G�����7X	B'������ *����{b�&����KQh�7v���)�aN����I�8B����g�hh:�:�9},��8nFl5�����:59]ednQU.tXD����G���D*����\����-�����5B�C�����$�Txz7��3��vCR���r�N;���^����������B����T:�D�bV��<�iO��T
��O���NzUn��@�JS�^�`LM��^&��xi�]U�V��j0��(����l������H�� �S~�_�;��V
X������������u�I\~4��;�����`Z��rl�@��%���`�fc��
����@��4���I�;�n!�nm�-��9�$��L�V��G�������,v2F�*�c=�(���AQ������}v��
�7��C;�'��T�7��m��p���\"�v��K��%���J�I�n"-?^�������C����-���c*L(�<T���`:c�oY�WD�qV7�qV�7j�V���f/���Z�G��T��3��|��T���R���]��+��r�=�48�}{P�>
���Y���D���I��i��~�(�58����g�r 6���3;8�@�e���~�yp��6m�����=�v�T�o����vk��h\������%isM.��^����?�i��J-�9��9�����>����c� 0%���?���9>�J��Vw���j,�^$�]pG<�b��f��|����;B�?�D2�������'R�����������8b�G6����9�A�v�apu=�0�5�b3N�_y�w��<��B����|0z�O1�)��#�
�E��-t��_n��#�}�H���A0�q���\��g��^�K���p��//'��������8�&������D:�{�N�A{i7x��>���p���hT`���4g�3u',
���Z�����v�o���#|v���Giz9�\~��\��;����-������&�tw:��__������l��A����}%��.AR)qTWn���aPAh�[��V"J2��g�a��}���1o
n��f����Pg8��O@�=�F���c^_[�s��z!���$���jQz��	�B��:Z���l<��:Q�&IrS�R���D�0Ln�����f���:�C��k8
�i��n�;��=���s<Z���V0[{�w���C��R��"����h�AW��^�sqjpv�i��H3�0#��w��e	�b'�'�P�2f1�	�(��RcYW!2*���2�\�Kn���������OT����$��$��a����W���/:/���K�5���+����,p����	���^]	_C�aY�V�r�<`}���C����pv�M:�g��cP�P��t��E�/%X;�B��Z.O�m� �Q����R/v� �� B C��kZJ�E�"�R�he��J�a�J�y��;�c��v�~���g�l���$�SMU����[�Bx��>']l����q���5D��5�[��3���T�i����"������A"�c+�Z/���#�40F:���c�R���,����2m�I�J�m3? :��.�7\t��-�X��BSJ��L�o��L`�����g y�>�C�T>vU�&_��E�V"����c�P�V�0�+P����{?�;���dE$[�k���G������8�v�����=8��YS����n^�����:��yO����#�'
��y�L�a�R�,�bv�e�����@�*���;V��@
K�x�&t�a	��2�
����P&�P�6�y�	<��������G�d>������ +}36����P�]s6Wk-R�h��Z+>W���s�C�u�!�Z`�S�m.��W�?`��W���M%����
CIa�y��s������e����A|��D,Q� Y�F��n@J��l�����!�����������>0
���K)�U��P�en�m1�Bw������WW+$�/��$�{��t���?��E��t�2#;�l�dXi��W�0���/Q��m����lJ���V������c�	���!��z���\�"yTGB���Yi�gR*��R��4���l��J�m����x�l��;h1
�g� �o�Y�g[�!��� ��/Q��m�xd�4Y�����w�D�^��������6�|�k>��������7i�Y�Ek���,g�;e��Ud�B��Ou:X��1NMF0�����VK��k:B�U��j���(�l�n�|$��F���8���ao�=f9"N�OH/vK�By��HC��u��~�2H|	kh����H�]�H*D����Ab����V(Y>��D�a���������K���MW��e1�]Rb�D@c�����h$lV��^��\��Ct�+�eR@��B"�5R��7�8p��2_u��S~�������t���!h������ R��4��>������@"O����l)H���Ow<{[F\��vh|(!�"
�QK�6 3�V�9+)���_J��UxJd%�1�tm��-����<�����T�����u�Z||
�yj�R��V	������kF!Z�,��N�R��'�PK�EH��
�x<�4LJ�d\�����=������1��������M3;����`1��+�������ZK���dKU)�G�����8�a�5��m�������#A���������a�� C{5��n�IO=��{��W��~���G�S �NN�G������p��{�'�����������x�t�uV���[[_.���+�'�lXgc����7�_�FY���+<���B����)���'��K1P1)	P2����:�Z���K��^�b;��&�)s����^�!OT�����xr@� +��x��<3%������C��Ib�<7�
����N�m��9<�Xq�G ���[:��V���k����u��a�A�t1G
L��mE�h�����j�b�
�s����8�����%?u~;�KiDd�4"��d�^���z�N_�\����o����F�����r(]�E?g�@��\lP/E&�<:?��u�Os����Z���@�������D����=|u�7�@���d��D5�/B�����$�e��`���`�[��v	����.�Ao��9�0�m�j���H�y��q0����d|�E�e"��\bD��}����j����� �����g6�Ot�qqJ�=L����s�n��6�������.��@"�&�P�1�T��#��
�(��(�P�������w/p�J8@t���{�{H�I+[|�5F���i�����G�(�7p�����n�!Xxt��0j�����!N�[;�'�g=���
@w�(?Bp���L<^4�h�o(��4�g���tP
JW��:xKt��n��6�Ss���*�^�4�+�>-��J!	.��aWaxo�*�+bOam"���
^h���Y�����{�(�w�;��&��u���%�ih-I�%f�D���|C&Ty�<fG��8J6��0:�1*^��.x�CF���LU3^��K�,�HZ��M<��%t�������iV&�X"'r��#����E����:��������o���/F���4+�5_��Qr�@K_��{[��ds�X��3p���q�-`UiE��X����!Bx��5�^2�@�U����������a�wj����J���2GR�!'n�����-�Q8�I��$0Q����@�t����_(�����j��Di����;�_�LY������f���:m�I�6���K�����[�T9\Y�;o��U�{�������NL�$��,\P��<�C�K!�~z�����R����I�jRC�){f/�<�}���~�������������?�_t�z����^�Gp�o}���@z�����G|�l�_R@l���"�{Sp�F����/Z	��13N�����H����������z�'X�1��4�1���=��Y)��'�7��?������G�Z���
�������M�Wg�5�����zpGF2������7�����Z���8� *�{����%�3��`�����}:YP6aA��c������}:b�HTb���R-�iw��n�/:���G�cszY�o9p�����lBT�yz��|9d�~����1<(6�]	����z�����'�M�%�
7��jA]�D�)/`��
B1�q���V9���%�!��H�m�@�>C��&0�i�m�5�_���2�|Bu+bM�1�_Abj1Bh�����G�f���D^���9?)��#�=(�6������=���g��]n�����&�`X���V��DH����+�	*I�)���Z�AF7�Zk� N]B�|Q��f>m)�/�`l�<
AG� �pfmt6���G$���)1�9(�0Q#=oo5M�F(��C��q=pA��_���~F���
))���[R����|���&�cl3M������
��lG,��O��-0���v��u��|FW#���A��6�G�m�'=o�
����F�D���:�VL���v��V���j����s�
(�t�ZcW��;mR����^�k�t�K��L�='���HS�q������b�����e:��<y�h!�(�a!h���2�Pk���7K �����O�V���~o� ��@�l��s���I�I%� �$�?]���fau����[@�T%�f��l�e��G�,��-J��i����K��BeO����a������k�m4��!K��x���`�!�N�{����7���>��FxXaL���p
�*%�x����z����h8��f��ae�8�^)��#����*D���xB����Q���������Y�\,m2�|&�1^�v��_t�y���c������/k{o)a��hM@��� ��>���x0
R��p]���\w�av1�M2�K';S��
��j�M`�j�,��aEF>����47�|��iX�5la�b��)��gV��z2�%w9Q�w��
�[�n6-��h�>M�����Rx�6������'�mZ$h�����)f��K{?z`�0m�z	M��hQ+��K�"��@PN��D���l���MZ��j<�!�����GRk����]��!��������Nb�/�sSS����e�7�;9,-k�N����X����ARet���HPF1�������(�	zn��o����j�j��v�`0���A��1�rK�>;F9�(�y��2�(�F3�p�aJ�v������77����h�������s�@���t�����Wl����8a1m�\����:�:�����$��i������0�)3��H���Z]L�7����#R{�)����K5?��w����Q�K���wLS��a�s���Vp<���������N�:&e�QY���7���T��L���h������Y���KQY{08�p��%`�}��w�y����^o4�E5�m6��
����w�
&SB�?��6J-�{Q2�\�*�����2���In��J��\[3+��X�J��?��Z�j���i��^\e]E�W�5���z����`@���wu�1��������6iZ�����m��$�����L���{?���?�O	Dc%p���5e���|Tn������}�*��dh��$��V��Y ZX��faW]F������9>��Z�c�3�+/Q��q����~�p�6���A���E�6���-��q���6�P�����i�KZ��&M��!���t�L����wUFKS�b���E��3��v�|#m7}�D�W�"���i5���������1T[v�1]<(w
G���NS��'J��g�"��O�{��h�[z�q�FKPt]�i������/u�FGY\'6m�ag�lWj
�NN������Q2���e���XC�Q���T�FI�5���5x�ci��lp���n����,�D�;&��n���:����@CU��@cn��=����E���y��r+i��;�*Mw�e:K��m�n���m[$��i+5�	�9�RM���j�����
���^�|2.otMZ������
Q�$q�#�D�F��VLJ�wI�Kf����&���7R<��%����-w����l&y7x��?7�������jv����&����b�bg}��N(��J<@�`�_q��[+��<l�1�5_�.�G�G�f3�3#|<Odj����Q�����|�B�xn���ai;��q��?���*�!�X��V|�fV,f�f�+����h���5M0,)��l��U��c0E��4k�e����d�]���V7�5.8X��O$w��L�2���U |�U��G����["������W����`�U���H����d[��rU�����_��+���6�I0����"�/��F'�b^	`49M���<��o�,�9��j��m�It�Gi�@��)����`���h���_��F�vJ��#���It����1��,�������l��Op����k��GO�:��~�y
���~��C�`6N�b�Mc������r[���3&�D�Ts?�"��I-��?Qu���Ct�V�Q$leI�[.�8��4���}��K�+g0��$
�����L������,���,����gXf�n��v�Wf<�-u �}r��@���������#
r���+q������2~������3��nN�u�]��7��Z�u���9: ��9�R0�rq�����u������I�L���z>�� �8�
&���7��0��&���� �H=��RQ�g����qD'�������.���,�~��R���_��))C,So8 ��N� )����;�#]Z���DQ`�������O�o������.�����J(
W4\.\�����\,\?"K�����_v�_�r!j"�����������{�x��N�Wey�������J���l^[�`��.������������E�9������� ���������������0t
��;���S)�����t�����>/�����(\����0��r������O���62
A��C/�.'V�����w��xE`(�� 
�,�k�����ko�]� �lq�)�����M A�@�ovs�����<��A7��R3G��m�o�0t����.[i4�*�T��� bi����U
�r�PV��XQL������A��F.�� 8��!���2A���70S�������CRU�<_���!���qk�~�S�Ne/6�'�%
K��h0 �O9�������i���b]��d��������b����:>Fd/W�Z�FS�?EdE�
�A���Pk$�Cz�_Uj�����5���@W��m�4%�MM�?�C�A��Q������/pG�_�?�����kM�\�7��O3?��KA�l�
��b�l�������}J��CVx���`��f�;�b��d������x ���GT4����o4W!(	M������YZ�����/o���~�&���V����(cbc���T��E���n�U|-�9����^w�
�4gJ���5:���VXy��qJ��t#������Dt�r�[!+��5��:��#���KX�P�2�M<8��2v��KNSk�
+���PgH�,�}��O�Kv��^�	Fg>6+�6����@�&�����n����5������J���'H��'�X(YX�.����ak���m4����g�/�>;+�}�5ws���k46������t�9����B?�]��?G�����O��zB-�+K�=r	J}jAkAR�){�Q���+����/t�����
	�`��
@���5��4��7����d�����c��Q����c>�l�����V�AV3�a�X`�d�!�WG�__���X�����Gx��X>���f��v����V��ifB\c�e@_:b�I���6!���0��i�$%���?��C8xX�rC;>���G32�$[������:���.VM+z�K�6���j�N��c�{����I���Jo�`%�,�
9�Y.����{��[G�����-�� ���OUP,Q����c��%���D5�������!
��@���y$�=�{�����vg�C�l"P��2�F&�Du�c������:��G0g)�@�����q���|����h8���M3M�Em���|T�M4��g3��r>�.�{t|��:�}��lG�Ao���f���w3E�7|�.�%�0E�b�5%����G�%�����st�K�������?x�9��<��������M����3���n���f�\�Y��/C��.&��&x�-L��UhM��`QPMg��?)����]$�C�;�qh2v�)A��)���)��K��<A�*���Q�2�M{��u���K�����W������Q����m���0>mR���������5��E����������B���k-�e��u����dpy�]@T��y���8���B�O-�>���0��Mo�!�/��S�W���i�����:$�+�0�P����������WDI�u�F��g�
]�f!�b�?����7�G�;;|��f�n���\���E����H1 ���<�R�O#���fo�(j3�(=\[�`��h��
2�(�?RP��6�m��s��p�-���	������v��4�a������%D\/�qo�
��=���*J��?� �vQ&��<��
��y�K��z,S�E�Qa��J������~������ti��,\���a4��$���xaE���dD����fF��xP4��k����n�=�=R�s���6@Y����v)Up�*d\���
Lf���dzG�n!A��O�
�f���>�a����+-
GY0��iZ'�!���QrPv�M��H������\���
CPx�����
��98f����;DDZ�P3_w�����h�a$5a�����x�����;�/|�����`3$���vEB�A�����Z�[K��4%e[aJ�5V���,��+�\��!�v��f8
�����H����,����Y[�G�����'7���)�#;�Vg���	�^G��AM���5a��� ��q����N���
vD�
F�!Z�4�0���aO���&\���?��-�hQ��R��Gb�R�=S)����1���$w�����J^s��g`&�QU%�<�.e^�T��)�d�Cm��[Z`�Ex�F��m!�,I
�(Y�0sJ����O��4F/U+1W�d���+�������^E(W��T�I�M;$�	z�|;�����S=�
��UH��+�c��`e ��B)�D�dB2�$��h�r�AiN�(y�m_��N}���Y�3L���h�m\K�����
,���U�L��V���S���e����[���C��@WL{r�6G�b��M�7]<���A|iCB��������k2�n8�<�/����rr����_��F���R�A���0���Y0�
�����wg����c�:��ZI��=<�G��M[�3�^�z����6`��I������1���Q���!K�u�������z6����1�^eGk��J�j�P��S���J�M����L����B��	�5}q�[��jlA3n>Y)��$������wu�M7U����"E~R�1�'���]�0_l��5��v��h�k����|�q�E*��OVq��8k��<�<���2�{7`��X�`�6SZ���a��70[F�5)Y~��qbY8���P������c�m9s��i�*(lH-WW�8�4�/�+{��qA�-�egy"���j���/61�0(�W�1{[a�wA5�����7��-��&�d�Dv��xt9�'n�		<-�����������b��]jIir�g����5e'V�~��Ca�������?�����]��Tb-���!�M�}nil�K�������*�������7=Ci��?�
�6��qo�'�Y�����MI��"�v�g��	��|���"{�����Le$�N��`�L�>w(�oc
<�gn��iVm����6O(q�D�v^dn�F�
�8��7�w:�;�����K�{|��������������6�:^��8^������=o:c�t�����������52����l�Y[����>�B�����z���w7�b�����0a�H��5m6�ub����7]�/���p�_�^�����������']�����$�N�����T�V5Y�����}j�
1���BX��!\�g]�q��\9��K��uM�z5�
4^��o�W$�nO�������-�
�|�=������KA1�3Q��j����G�Gr1����KdD'�����������Nr�*�l��z���`Cw���9~�QS~:k���:�
���#*����mB,
���Y��|bb0�����\��������7�3]��y��n��"8�(Mo�t��a���rbS/�`;�]Q$G�OI&�w~��y���,B!3�����x3ZM�o���a{4�||H;S,�����&���O�����}7C&��������6�{5w�_�_�l�Wq�B�����s�9�9������D����{��_���$��K� U/��M9�������T9y�6_D���%
�����,�pA���bO+��`�J=*u��0���8� ��%�~����V�`Z.��sMA�
Fk"	# �d5R���:H�`�v{�
�F1R�F��d����i�JYU;r�� �*�����+�qx~l�)��#@s*��Ld��	��pue8����.2�G�8)�SX��`�>o�O�G�n�d�#�����xs�A��Z�t�VVgi����.��7?}��3_�
F��~�2��q�@�|��[����8C&��-M�/sC�N�r���z�4�rh>�%�H�	�����p�#�4���LDB/��k�j*SM]i�k��wn�}v�"�
Wj���?��x7!KW/��,�Oq[��;�=O\�M��Y���DMqj������q:<��Y���A�	��t��Z]1��>`���d�R��N���F(~=?�'���/PM�{N�iU��0r���}Es�<�P�/);M:�j�{���F���1L9�h��p(1������S"����0�u�)F�=�ns��E�K�D�*��:�N�8���#\Y��F���\[7���
���w`���Dr��J�����v��u7.���]�h���J������k<���(�S#pH�r�W�_�p�S��__�K^w<��jd�������5�f�����y!
Q+��[�U�:������f��:{o�;&Lj�^��E����9:��Z�5`N��������6Y�l�BG�@v^��� �Z���k#V�����q��U�Q�f{#�;����������[��qT������ch@)n&L@��_.o����r��7��fq����D^uow�NV���Q�wR��i;pS���[�1=\|��6�8x����.�'�k�qx`S��zoi�����6��S��K%$���0�q-��������o�r+f�X�������]3���{m�����x�������o^YY+�v�O{�5��hg�u���{f;?��C���_c�_w:��u<��!�u7n�.��e���������_�������0U��d�gewl�@��������a?U����*���,����}h�\��9�t��c���Z�+�s���<,�[��w�b�3��c����5p)���x(��.Vmm���T����������Xt9���4������r��aa���K���?��f�cK�,��&���|�9CM�����]}<)Q���v�����^VZ=�Dk�%�t=y��a��,�.-��6�������{��wl���7���.}������l,�a���`��'�3�y�����q���BZv��X�������}������`��FOi�1sF�\Q��Z�)�.��>��iey�(O����0����`p�V�o������o����z}x��y��B�`����xW�D0���A�U}M�C��.Ngi-��Z4���
6M "�pH;�M����ag�f��A�����`C�b����z��&�P��]�h�)+j��
z��o�lX�z��k:���m��yMG9CP�:}�^@%��g����������W��5�A����]�����=������#���Mgt��9�S�0�]��#�s��-�A��X9��)3��imz�&����k�+��]��k�i�4�=�������v_[��J�rZ�������niz,�8�6d���pdU�f�����ro��?x�����nF��d'.bT�u�Eu��<�|��e�y3b-�f�b�c��Y������+�7��p��5�z[)����B��{]��h4�M�w[���h��Ja�N*���U�R�?}�b0����~�{�#,�@���6��U�4�*�����r�����Z����H9F��L���h��:���#n���(��@NE�02��a�$!n��L�A��`�y��:lE|��r8���}*��)�+�s3*��2c��1oED�doL�Sk�U��v@s�_m�x!���_QA��av~F�x���������� ���yO���5�/�;���"��kT<<
&	j
��h�$����������������<y��<��
?B���7xNF���[��z�i�����GA���e��t�sL%�=����U�)�_.���sF�����;t���B�=~��C��;�7�-����0=@�EL�
O���d<��1^w�1'��d,���Oc�1������h��oEr�,Vr�;�#���Y��4��2���r~U�\�?;��"�K�W�w��wi �2��J����p:6k��c<!����<�����6�9U�2�S-���%��Q1�a����?�������%�#,�b�����H�=
�|���o%.�48lSS�d/-����FD�b���9�maHd�a0��������#����G����[�s�
�e���l��wM����:Ap�0m��Ly�QXd���jMw�9b��XAfc
��!`��Y{O	���d�M;���S2��b��Q��~C�t�����6X���Y�LY��j*�tH������!A�h����L<C-n���>������0�H�}or'ZpL��z��4[�nCTW�N��5)�+#(8aq.F^�5�<V�����
��9�s
����E�&��|-�{sQ�1�>)��|R`s6<@�����JHWVWsbI��@�a��GA���1��S�R	���_#�����N��U��� �l
c��S����b��U�
�z���������rD���t�]^������������D!��0.G�:�Eb��5^N|?B�@��<�����$c�x�O�S��w�G�;Y@��7c�UG��
k��QmC}3��2�������x��������5c��A��m1��[c0�D��u}3}�Y`�y
�7��;��Q������*.9�����
(�7QM�&��#E�V ����.}�c����vM�R�1��LW8�9�����T��0���U�Y�\k46�7]��a3
��L����������ol�S��xX����h/9�+�7��@l"��`t(I������.����tL|�������f���{���z��2��J���}H}�m����1 �G|B����d�+�o�HS�����'d�N�����WM����h���������Wd���EH(,��
Y2��P�X�p��Z��^4p�M�*�e��\�N���I5�R���x'�A�o�N^������_G�Z�G�Gu��\�x�?&�o���60�e����>��u�B��3��p,����3�KH}E�����:������������3v��8��X	��R������p���mR������������cdY�p]�	_����Sx:��@5�*���(<<y9`k.Kr���{k�����@=|���[u�0�F'��x���3�b{�����������o9fx�m������������8]
q��s\(��f�u�46����8����[ia���.���t��L��`%��z0}']$�T�A����a��%��	&��JD�����g���%FO1��	|�i
���%A�C���
���g}�YO��C����Ktt��Q:���z�r\#?����g���&,������>V�,�=U�
��)��3,-�BEV�D�i����D
O�v�F����Y�`d�h���c��N[W��V�(q�f���_.��U�����pU0������%�M�+Xqg|%9�2�y���������}x�d*���p��@������IT�O�Qv)I���G�Q�1eo��y������6`U��.-�wJ5+�;�Q&���"�ts���I�YB7m���\a��'6W�p������Z*����<���X�h*�8*3u����w�mk�������iE;9��8>E�]�&���l��FbS�n��S�e0
1���I�!��h�	��$��y���;p��9�`��Jr_6RT"]��w���D���E���W	A�A�����,O����,��$LDY���p�v�~���6/Z=�f.�$MGy������u���r�fTf���dd�S��CQ]��kJ�X�*e�R��?��Utd���a���,��t�r���.�f[i�:����[{�@4W]��}�}�����CxRg���m:M���_� w��>��*
`h�D�]p�n��3,���U��z�r��?����+�&r�q����2!����X�_�/e��_��k��2WM��C��.��\�:�"f�����=������c�_��T�A~��m�d�����W��j��8�ko,�P�*�aKN6O��n��c���[>�y=��.'>\U�E�<��)FM6�7�E�-���RR����#�i�O�w`�h2;�/�������[t�*r�xg�&�C)��+���N����x���qw��s��O�����x����k2q�w7�w2"��c����P�������43��s��g��L"~�ix5\���J�2>�z�X�4.��3���j������yY�%���%��bi6���yiL�H0��1�;�fn+�'?�b8���b5��k5���j1���N��{le�XFA+;�<+;�������|�Y�y�����]~Za$�k	ON��PL,-���������wZ�O��((����D����j��~�#�k���rG5��Q]�'�tQ(���H�g�}�6=��o���b�E���c�� XE~�^S�s����{���bg���)�v��� $��T]'��iB�B����Lbe�����N~re�l��-���T�.:�����.�W�� �����)���.f���j��`z
������o�SEQ������"�K"/&�	�\���6(N������>���%@�V15R��%��Uj�r*-��Dt���+�I�
`����vS=,m,,o�_��3=�	
�|������	���Yg�����
��[��!i��iU+$~��:�,�89��,x��w�D�A�P��V����H~�f�Dl4�!��������f�(~��*|��-���EH���[�����������f44�U�F
�]=L��G5�TG������=\:(�[���]x�)|���/�\C��q��uh\���b|q���l�7������Mmd�@�"MJQ�/+���Ww���,���hQw�L�����tn�L���s�<��k��fo�H��L:bMY�/��0�,��
�eh�{���/kr���E.u�p�qle�[[,�%��� n4X���\*������eQ������F�F��ob����}��km�}�flbd��P�c�J0����~�4���n����PX��4"�������C����"�p�6I��{�~zP���v3M�u�c�jQ<TC�"���nA��
�>��n�w����������=�m��)�))\�����^���G55����
	���dU/�:�H���P�!��`�gr &�2����W<H�lQ���%e��1���G�(o����PO�z�a�	`G=�8�2�S�'�b-=��q�{�����u��������gc���<�i4���V��������VG���@���&����\S��:���������W�"�{�L���,?^�""���������QU�=T%t*\v�d�=�$8NAp7�F7�EX�A�H�����M��,)�����8��y@v�������!'��S-Y�n�qx�����G
`���m%�M�������Yn�-��$ ���UM�eu��1�G��T�0e�E[$����:��9!8�����z�����\+�b@��b�=������{n2!CS,���)"�S�f�U��b�l�[n��5
Z��<�^�uV#h)OZ�vm�L�[R���Q3E��]�K�U����=���:h��VK��h����������H@����m�)U�P���Bv��&u�	������}�!�3.!��NN����z�`g�E��r O�A����W>D�Y .�7b��]�/:��WH��=[t+zt�~����{r�8��=��/�0^l/����v��-�ho�l�_�BJX���[�iE�=Y�����J�4<O7����q��	
���|0�?[��'���B��v)(�YP������Y�k�������Q�-�I�[���t�}/�5V�>'�l�o�?m;��������a���|"w?���g��9o�z�'$ B������[���?��8"jUz�^��o�"V���UR'�}�����
������!2��Q��,�P��2	?��,<�B�+K2��_A�p�7�]���%l���x���+������g?	`�a��",��g��d��B~�t4�����r9p����u���y�q<8�gor����W��	���"�6+��V��\&��|��HS�����.���HmE���W��7��
 �%Qb���FZ��'s	�Q������C���s�����N�!U����!����������&������4G3��`��#�	��������g�Q���,iF;*(@GQrq�Yr�P?��QG�i��v�Y��k��p�������k��@��$�6d"oq�.���V��5;���i�\}(a�JN�R%��6���K�Yh����[*z�Z�d�PtA�L���[�(#@�P��g����@m(���m��Y����d��wY�e0��7_:��d��X����p��]�	�������D��"�9�Mp��#�X�8�����S
��K�Z�l�����8�m+��������ef�9if6����9Q�)a'/�X����|!$���'S��zoD�0�oF�����{B� �,J>{�`�m�x2��k3t��[��p��lp���3�>"
�H\���p\n��"Z�0�K�S��%���~s�Z�&r��P>�N��w.|��Ha�G�.��PX���d2�Xa��2���B,����3�V��%p"����;��u& {��H��R���v��EG�rl<��|��"��t/�����1�T��1�\�$*R��'�W����������H�
uBp:���u��M0X �6_z��G����!�T�����	�"��o8��%z�QV���8����6H����_^����*����
�O�"�)E��7�a�?N^^��
C�^��!��R6�K�����
+��r{_��D'��R#�e��}-�[���!o���Z�Zw�;�������w��Fj���Q����E�`�_�F���L��j]9',H��� !����%��J���f�.To?}����U�z�2��RX_��5�m4CQ,��F3,�6��QXq���H�Y�yw��'r���9flN����#qN����{N�g�xV
�F��|��+S��	��!���C�l'�O��-��2#����;����I��T����n=�u���SQ]�J�E!k��r
��Za{h�����������Pu���>|h�~C�ER�O��q�uO�"8��^��A�`x�����fp.��,\������|�&�YB�wF{�7�����)��9���0&�@�TZTz���q%'�����
���������	���a`i��P5��k8��b���JD�xW����
��b�p��*Qc=�h�"��d:Z���j���v�����|������Ei����@3P�&5t7#�jQji3r7=��xX2��i�N\y������bv�2�8���fC��	U��j�"�g��P�^�����j�i��1�`�J	���E���
JS�D���+x����B�����"��b��7����>���,Q�����
g��iH�wB���@!�t� ��BI�"�I��T�5�gs����,�2Z����+o�{K�[�x����u�,zg/'M�
<��~��!��#hS�ZU�����O��n��zm���65�����G��1�T��F����
���Y�������������|����f�L()�=
�y-}��B�;���@<y0�|g@���|\qqg@U��Jy��h�<�����U���J��N���5x��l���I!s������p<�P�'�F&O��4�m/����������l3f���[����,\s�x1�Cc�#������'�������V5M��}
U�N���-�>������h�7�����q��8=����"5�%��aK������4���Jw��Wu���V�]#���pxB#�qA+\[k�a�������p���6)l��������^�����G��-� z�f�|����@'$����p+��;���(�"��I��|
�[,�n�[�7��~4���������6()F �z�"*�v����{�LW.p�)���\�����u��S~1��(*���h!E�V�N6)���18����1+�l�������8u�4:��{��
�Q�8r���pH�17���������F	����xb���G�:x�@����HD����p%>/N�m��9��V�^����B�y������/��y~VK�����K>����s
��y�������e�y��6Y�7'cwsK��".pu���>(;7'%pm�Y��=��E�]Mg�d6%�>++�q��+����U`�D��xU@���W3���u�$�������Ov��#\��'5�|����]R���M��5�	/W�pR�X}5��EaU�9��d�O�U���;V�d9uaL�b����;���T�~�t�u�||G��w�����oI��^����R#�/�	B(��H�\�K:��-�����B�J��D����F���z��PE�4\]}8M��U�v�;��"�Fc�i��2G���?��p_��3��"���!������������
��;�����k*���f<4���C#.��dr1�\yA�������/G�?�����L��L��<��zH���)���Ao0���~op1�y3j���P�V���K*���
�1��>����'[���H/�����#O���?VT�I�3�_�Lg�2#�$mC��4��V�m:�%q�3$���_]����T��IY-U+
����\�$"��)@�L�+YL Bfg�����V���W�N!���f&���U������h����D�b��n�-�7�R7���u������Gg��?����O���-�� p�
9����������s�?���V�����ut��VKl����B�t���k��j#�
�fj%F�r��K[D
�?7��q=f�kf���t��c��d1�0���������h@6��F��0H�0�<I���>9L�"����)�F���v����t}���$��4����0������|�m��E���k&�G���N6�4u��(�wu8v��_���������p�u8�:����_x7�Y��,-F�����y��abZ��W�l�.�Q��s�E�-y~��7Kz3���U�-{���u+��~y����H	��mX�����:�u������,���*����#f�}�E0�>�K6�.�[v���y%����7L6�U��O���&u_G����_����Mg��n5[��k+�������G���r�@-�f�J,8�+'���O7�V�D�S����v�T����`;�7�����v��X�lL�;�C�(���w�+��+��?(A7�l��4"(>����s��~S<��_JS|C��MU�2���F��*�>X)��|G�9��z,�/�:Y���Z��m,��Li��X�F�b��jD*�h+pN(#��3��;C���;VA��W��k�t*��ol>���645k�U}��Sm.����Gv��46��������D�hP�dr-��J�6�Cg���ZL�W��)~T���~Q�O*H�0� ��R��5���jc	�K��$�"I����dv$�EE����w��u��)5��6_\�Y���X@A�6��i������kk|A�X�?_k����B�d0V���p�H���k
8���S��\"IP��~�$$q������Z(�M��Di��*5G3l�����sl�����Z��.,1{�Dj�$�7���&������4�}�5�kB�����v��-��k��[���^����m�����t������5��b�%
���>D��qI
��V��:��
��Z�������6v���e�P��I���ZK����5�����c���YN�6>2��+H���/�����I#�����i~���i��Q��f��(�p]rNO�k�f����k��I���9��u��
� ��f �T�kPS�A�)mYS��e��X�W����G����q��xG��aOZ����`����j:�����:���8�x��eA-v�-����T�?����7�?�Y�J��� ��;�����YzP���U�c�7p�
�y��m���dCQ�������9��Z��U����&�����+����z����"�F��c�>[���~~^ZE�b���`2�}�k���c�j"��|�g��OLBWM'fn�x��������H�������EV5!KT�B'�M�p����`:�fo���WFmb�M����y ��(�r�����]�7Te
��k�+�����/3�=�NzOf�t�d�_�SO��k:���'(������M�����b0�����S��\k�
F}��4���p6�����#J#y���?aO�T��PQ9��58�Ts��m*�6�y��u���(��V���G^��f��E�6��`:�p��f��lq��w3�[x�:�_��w����K�z�����XhD���_�b2L���%WTS,/�i`��JK��t���H��*
�����LXr��f����_�����a+H���0sw�'�e��T������������ynF��
���;���_�����f^�#^��������p>��1�F��U����R�����I�����7h|H�2W����)NL`�BO�0�lL�me����H ��l	9��W�U���������OU��h�L���
���\y�*�pw��*&d��m+L��<�Z ���pd'0d�b�n�d{��;�	����'��l82����]��&y�}t��C����������h��(��5�;��&RQ#.��{@Y$R��R���N,������[�;}j��wS;N����V3�d�"��?o����H1	�9����WQ!'y�!��(?P6�.zt�������p>�����$�Cq]/�����7{�d��7���������x�{������A��:wc�g�$
�����h�
=�X�	M��f�)�CF:
+����$���1"lR%n��������zn4`�3��d�-6����o���lxYMs�:������(?�I�a=o:�c����������a�T
��j��gh�GcxJ���4�������5Wl�����?�E���C���D����������W,��,�&2�k�g$�������� X�n�"9[ �S({Z��n�z�,�/6�<�`�XCf�,�_�q��F|�vt1���}~����W`d|p�n�;��s�l��>��7���I���{7%����������!a>��9�lw���W�����e�S���sq./,N@�#��	~�X������5�����'�����i����i�O�>;EB����~�<�#-�L����
�2�d��������L(�tR8�g����
�	��f�
wA	h��!���<=�P"�`Q��L��e{����9[)Y���0�z}�[�|Gcu>�Cl�='���)��@3�e7C���Ul�����"oe@��#����\��������h0#�,73���c�DJ��=e��''��-m���2!���;�#A��?�.��5��k���y���[�x�"
�� H�;A�Q�CcH�+��Q����+�����0�|�O�����Bn��[������B�hZ��E6�:7Mq�P�K�^���D�L�pQ�Tp��K�9-�V�-�����s� &1�E�ko
����73�{,h�MCbe`�t���S0Gz��i"�ipg1��l�X]Z��i��~��M�lp���>:�&��\��|a��.o2gq���J����	���h�G�z+Gx�t�n"D��s�}@�������&
a"�1�+\K-B~�=����1��p�����m�s��b�x�`{/s�7�r������2�PkCV���2kp�H8n����C��-��_pv
*�-s��du8>q���+8\^���J�Fx�p�����TS�^��L4&S�p�E�|�'�@�Yzb��[��V,W�x�1���0�o*�r��'�O��b~4W�x��g��R�#vQ;���9�D5���(��/i9-g�xO=3$��,��taw�&�t3�^��R���+���C���$\���d C�7���
Kz+���14���JF:Z�;F��)r���t)M�#�M.A,��'XQg}	a*�!��xN�Dl9U��RXd����7���|>Y'Ri�B!�5f,z�X����a�v��~��g�(F�Q
���Y
���Uc4��d:Bm��-���~c�?5D���I=	�	���yM�����s����b������!9:>�%���W���H:�kv�� C�[����;���`*���XEr���>b7S�JT���5�]����[���2����Ip|�w��-�]=��A����8bu.��P���r�
�H����������<�B@�����~b>�t�������_�@�����=�p��<����ET���[�TH^!�
m������<;�I��L��!�\lY��tl�;�jE��p�s��6����52}47{t,B�=�����)'E�|���b�F[�
�-��.5���6��&k,��$�	��duP������a�]_�% �2������X4r�g�S�G=<2&�1�&��/���FC\�7��D	5��6XA[�����|(��A�^�q�;D�����e�lN�=��4���-��z7�QW�-�������c,.y�l���k�9�]���_^7�|�`���_��"q��:r���%�V�][���,~�ND����0�P��Q�rL�'�����}5LgI����'�Yw�I<���a����x��Sz��k����o���"�%�����F)9�g������u4`=XW�
��Bu�/)����%k��Z����Z�P�2���-Ci(�eWz���;a����O��"w��\i:��u'�*C����=p�jdFXd����Y��.�U�����3�KX�/R*�b���M�b<�7f�-����6o�����3H�b���H��}�D�C7�tW�(a�U��I��'�$����tR�j%����.�JK��L�q_�iO�����f4���r9&��Tf ����,�RK�{ H������c��,�J��U��(�L|���dH�<q�g~�9��!�Y��F���=���G��;������������O�o���n��I��O�M�
)�%�e��I�w#[��X�	���P��3I�.r�R�x���L��Yya0�,ji�����G�VNjdj����+_g�i`c/�U�D�*��/��w��l���2�����8�9�\$�����i�g/�%����h:�P������������~�DHeLH�aB��~�+S>!wt�&R�����<���p{w�X���I��������=b3����Ti
��E�"�����U~��F<|;�8�8��������bAJ+J�8���SM�|���/�O�������_��I'�%�tz]%�5�q�M?&��zT	��d
u����1n���M*$��%��N�ze��sx�u�>)]�t��^C^?���0��yqi��� ��>�.�pb1�������	�Khhd�S�~]��~$�[^$��I�J�w~�3�����44r|3#���e)��h�M�k�����/D6�[LKZ�X":�h,��S�a	���C�\�yL�~8�D��'�R���E�F�����u�T�6���I#Mm�&��P�b ��7�Kf(y0�$*W�Q	����|+kQP*8j:����E��0��9�Jck���.��+�h�S��5x)����c��#i��������O�������O��L�\�r.�������d��e����������e��e�9��m����s��d�a�n5��u}y~���a�����^��
[����l��/��<�<���)�8�/i��N��D��/��Q�l���e��G��cB����]t�#�K9�a���������4�%�~0�%�)3���5y�A���`����1I��5Xc&�F&F����M�����������Yp;$3�a�/�yY�[IZ�{0�Z6�y�0������2�>�5���u�5���8<x����4��>����Qj�So������%v�����`�|�E��g�f�8�Ih�R���8����������a�!�I{4����SSn�yl��u���#���-Q< PD��"w9~�	3j�+d�Eg���5�f��_���T��F�����S�jq���Z�������{=���R	f�o�i�
�B��Vs6I���	S�l���`bo�6V����~ID��Gu]���$�����|��h3Y����*H�mI�����J��(JZY)i%Sr��������*���
�������2�*���o�KBD�&��E�U�j���c��R����j=�$��f��9-*�7��Y���\��)�������U���������t:�����b���C��m���l�QE���_FNf�0 �7�3;�X0��w����7#���rw����S�P����V>���>�G�gw�+��6+y)��xPui�������Sq0�A�+�A���+�X����+�@����OO&dN[���&��M.�fd��\Cy����9�]Q�c�Z��mDR�-���`�x�cS�"�"��[�rgYw���(�/��W�j��q�u�E��v�]������.\~{�S�F(E��_9������1������/�������	�����Z��$j�X����le���f�u��/�R$Som0RI(��z&s�m��D7l#l����&����}Q�T��+�jt�n�5��M�P(�8 �"59�:*�5W"�6D�Jk���!�Z�h�T���M����e����3��X�Xf4����a��N�m)C�b�,��lO�XU�@=���A���$!�2��K��b��tmCma#J�&Cpqc`3�`���(�0R �n:�6TG���~XYW�v���L�y���R�Gpf�b0������C��� �4�����<+������-�����m�����676�������j���~�����m<�k<�*����q@�����BT9��0$�n�8�9� vC�@���y��L�E��c�����
�Z,[�a
#+�:&��-�eL��C�����H��B%���5��}��-����k�����p�H��ug�M.�C=r����������!Mt����)�Dr[r.�WL���Rw<��&�����}���.��"\c�rK4�3��I��Jf��p�����)�z�>�|���JkG9�
T�:L�-��mYmwM8���4������Oku=?5V�%'OV�\��s���o�����y$j���F��^��A �1�y�K�Q�07���a�^
C�Y�s�AQ	0�b�F7W>u�,���e@w\�>S��ol;	9�9f�TIo���f��9q�hb6hl�e"��<X 3E����X���8�/��Eb=�����m'����
3���tN�S&�5f��
��8��#��c=���~�]�0��8��7��&�
��k��M����I1N�j��Y�������p�A����w�Ed����E�"���i�k`J�����<?������? q����&Q\�����y�i�z��\

|!�(�����f={.�~�9}�����6�X>�b�6�C2��^����k�����x�A��fP�<���r�6�H����=W+FT2b�Iu$t�g4�J���nZ2]"��7
p�I���;����QV_��U[���������/��#E<��]�g�v@�k_PD!�uG~�+L�">�u����[!��4{�Kz��{v��>bo�@�WF������5l),�����!]R�M/U����}�h��>`~"���'��'Ad���������K�K�&q68
@K^g����hH�������Kb+��g'X�����{�e�,i�pYOb���I�����k�����I�t!�����Yk�zj�`�)�`�0T)M��� lx���-D��-��_p��-�t����z����;%"I���-���)cb4���W�9���7\bQ?���'��hzb�����V,W�x�1���0�o.�r��'�9���0Y��Gs��'�z��(%?b�U�:0g������E�ZN��'F�w��g�dj���^�����?����@�f4��{%����LV������Z�D��[J2u!��Q� �${��F.4l�J��L�U<��T2�<� �iZ[���:*�;�uv���z~x���5�TI�Ja�%>����T��>�������U�8�sY�E��E��E�#{VEa�.Q�z�Q
��Z����h>m�
C�>��5���0���IC���M|K,��N�5���1��������!9:>�%��A�T�Ivr���r.�'{r.�X�����;�
�`*�6U��q���X�5���W#���'��>��� ���v
Qzc)��D8�]s��y6����z��e���4�#3��]�o�����L��V4<�'��wV�D�Q��e�@������U�v�;��P�h4�������R�X�/H*2e%��S'!��<��%�"$�p=,��B�
�Th��7���Y
O�tg�)����.�e�.��K���9�����Se�]4���0}���I��_�����#j�Em1+��ZL�7����0�i!�E�X!�<�����k\&���?yT�qw�ax�V7����1�������Q�T����V��O��(<j�U��)���?��C�y`��,�G��R�f��s�kYa�Wx�^8?����6_|i'�������f�]���7���i����s
>�����b��>#1h<'���O������th
H��j��j��B�Ck�0~j�YxU��U��!6���C�ivy:Ow����,�[�B���>�.<����!D:��C���n~qp�Z�r�:�Hh��<�-�QJ��I����u�`
XG�������P]�A
x��'k��Z2��&~ ��������-Ci�P����@B���AW�Z������nq�zh�=���^w�k)�0h_�G�Ff8��h_��B�tY��$���Ao2�~��Y%s�V�XJ�q�~���DH���S�{�#�� ���Gn#9��� ��=7�3��J�z�N�D��D?9_kg�%)W�M�fd�j��%���&��/���;W���7��?���q�~�R)���P�g�5)2<�������V�X�A�*rc4X�&�M�i	2$b�{�������,�W�]J�u��#M�M��xT�����?.�O��)�n��I���O�M�
9�I�e�-F��v#���X�
����[��E����]��2� ?9����t���@�`X���������F$SC'�35\�&���Z������h�|�7}�>�]�<'��=��~s^�PR�@��Y��^OB%{��t6�j=/�o��!���)�T��4�Z(�����w0���$q&u~��q
��N���w������������P�d����-j�RM$+�%��jH7W�JV���lm��4��8�������bCF+J�8N�Bc
j������d����sZ���v��Xr�k�	1����dg�(Y��$aF=������ �P}��o������^w����Mw8�5��i�#;��c8��,Mz�����!&}^���p�^0�	�IhWdS�~]��|��[x$���I�J�w~M2������4����ly`Y�H�"��T��.�mcu���^��![�-��%�-,�%4Wp�
fH=#[��,<P	�&�r{��2�HPK%Hg
��b�*���E,�b�T�U�tv(B�����n���Vr4��f�l����V3��T`�znmu���at�s����i]�'Wh���4��k�R������aGR���w�����:dY����M�(v��9��]�)�k<r�]Q�4\0v�2��J����i�u���o�Hzn����]	3������Yi(���b�jl����������z��w#���'�p����
Z���&}�������3C��R������4G����{��!yi����9<&�'>0���=%:��9�����?<BL�����bZ"�cZ��2C(Y^�o!�F~�
��J�h�-@��5Xc��4���<,3n:3�����o_/'g���\��X�_\#	��h+i��yk��������j��z��|`���
��r����u�"���:�h<�c�G�	���+��8�nK�&Q?j�����������q���t��M�q5+=-�i[ �M�.D������OX������tW�����(S��*H"�K�����5r3/9���������v6.���x�)\y��n�p�ee����EA��XSo�@��	������)��FO��X�^����SY`];a@T��No�������g�4t~}��R�;�7���/C�No�������^��r#w:�������v�)���K��S� ��sB����#��L���(�)@=_4[��k�}��z1����i>��,v"D�x9Q���i�h��c��_��w�dJ^����oa�1�����l�
#��/����J����n�<���=0wV�����=���y�m6���VS��G	��i��^P��s��������4���P� |,?�(�6�������G�eCQ��J0D,��V��@Q�7��=}�4`J�EB~���Q[u`�w���&��N�g���,�����)X'�8���Np�	*�	����[^��p?����Lb�~G�.���}|
������[:��'>y�G�w%]�Kd"j3����(]_���I�87�)����(�4:u�����,MU��Q�h%9�;��0AZ O���5�����Z0�Zc�5�c<i���3�#*+I7�Znb(u,���M�i��H�Es���0�O	P(!Lt��J�^�bCo:��'V/b&V�.�FD	����/�
u����#Q�Y\�,�7.�qD)L'���I��� Yq�d�jd?��$y� ��wq��vl�:
r������N���Ss��<��NoW��7��[?�������6W�C?�����;p1��9�����D?����w�K ��"0��'d�{B�-�����=;A�����t��":����\;��9L_�@)��f�\��`F��!n�%8v�?��E�=%���
z��3�z}y��=O���C��������
�}it)S�{�j2�P������g�D;�K�tA���$n$C��BoF��0h���P�RC5����?��E�Gk���R�rb��v���6�Fh:�&��6S8
v��H�A��������3�(����e��V��i`�$q���8�7R
�N�S������#��(�X�������N�|I?�������4����Yc+������0-��~v�j��C�B�-iq4IT��4�x�a8�%�1=Q�V�<���/>a��Tq)b2{>�e@�,)C�YP��5�R(�OZ�V�b��$���7��������n��-����VsWI�����n*�pM���-������O�U"(�v�tU�pP�����������M�BtO2���v1��4p���s���ya����j�M�h�P^��S#)Nl�$Iu�2�e�{zp&�"-���~b�}����k�t��_�K
������4J��o)�[B���2��#
(6���=��	����
lD���m�j��Z�X���&\���85j��T��Z/�q�BM��A�F�Z�X#o����H�c�E3"BHTa���v Y�R�<�Ch�X�kL���\!u���O���Y]�����S���u{�Jz;�k>~�M�U>�9���/Q�I��x�=hMbl8x��O�K���� ���"�Ao���������!N�0�X��D�%������=K�nZ�!a8��D<�[Y����L�o�"�4<&�
�n���(���*��Z�^���t�F�op�$��l��M#�G����G�Z�N��?��J$�{8���R��P���`����y����|�����	jQ~&��l���~��v�j��I������S	���\B��8p2��u�c���NcLm����k�m��xD_t���������'cor�B|R~E��3���������\�s�m7!��9���lH0��������>����lLpJ���O���=:��� NC���9��h��G�]���y�����.��h��j�J����f(v��]^^��xo�:|��7����7�;���Io����8e�����U*��!a(��)yN��(\
��`��>��A��7����9;|q3�Q5���E��������[<f<�pb���X�A&�Y�hi�h����L�MLHm���@
�{^��D��rO�^!��*X#�NI��!�����##�mb���l6]����U4YO���'pE"�"�X�c4kM�+j�m��r��X9r�V�gx�{��L	��8S���@��:����Y�Z�S�j��9x9o�_n���{�lM}~����}p�a�Y�G��������JC�����������{�/�EBEY���P�����HI! N���)�/�p3���8�����5���7����,�F����+�#����hx��t:��%���prh}9���-��B�D�<b��4(�$q�}w\�c�p��@�"HN�a�PI�VY���
�8Q�O��Xh���!�GnnZ2��a�����e5��I��� n�/.���X������BD�I��1���[��#h"����������e{���/���_T����������z���n��LX����l8�����5�;�n*X�E��j���Q�\R�SZ7���jz�y��N����u
��:�
�>�K1�hpR�W8s���(���e-lliv}��AJn)Kk�
���C$��� J\+*��MoqV4x~�Z9t�Q����h���(��+j���+8O
�r���7������Fz����t0�k��|-B�#n�6���E�zT]B^�c��i�-d~,�hg�85�g[�H�	������p���n���F{��/�p��Z��>����z	����?
8
�x������,M�C*�f�8�OU�Jv)���.kKI"�G"Z�p�GMG&yx�~)"O���"�'+v�~La�H�'��+Q��t����3�Ba+��8�b�T����,��w�vbR�R0<��f�2sW�u��o��8�����9�g�B�b�$]��~<-uO�gb5�����lG������I�)BJl�.���V�hoIt��6��k.�4[��Y�!DF��K#v!1A���w�g�S��t��
g��X�A6���!z�����q�l��%��$�8�41rD�����(a�o`����l�]	��X@T[��e��H���X�n�!���YT{� ��kC\:�7^���,Z��{v,��b~�1q��O�eLj	��J-g�M��M=�������W�e��0^p
��������4Y�eL�����o��[8�EQ��o��>��{vb����y�]��{d���z�g���Z���c^�
��@7�n{VT��}��d�F�\{�YQ=�p���V�r��hM���lI�-D�8�._�;�i����tH����Z����d��H��$������2A�-�e�����JeFG;#�$b+��^V��]����,�0s����*D����B5;��r��(e�?�8���}�As��j;fjwD�NNK���i������<��61y�R&:i��J��DXE�q�-$���vr��I5T"�-;�_���J��]�{3���T �qyPIW3��G;'����� ^�G4��eZ�����Z[���_��]�TA�'L^I�O�|�����w��Q�����������5--���8�Kp�g`�e'����n��n�,B7nh�WP��6�-
x�-���@w���i���N�����(�	Z���� �e�e�i�����%5�*��s���Hf�������<p9��q�-�~��_
�,�}����mE���UN��3��K|]/������S�J�������a�1�
��s���
�@�*�B�R������U"Ro�^\M��� T?ID�s���m�g�_d��M��u"j�F��zk�$���8���1��e�|��;�HU�y?��qs)��)�@z�����_��4���RE��&(�XjLd�R�9�M!K��FN.b��k�T���	����{��g�]r���3�f|��Cb*J�).*8�q�P�]
�L��{
$��J�)��.S�d,��$�k���3�3�=_��3O���ff��
���8��'�`��0K��e������M���v�s�H5L!<I�lI��{�X���������Udb�BJ�Ps�>��za�sW�PRf	��l���6���Dv��$;�r�?M�)THJ�%c���}������������g#��$�s��.{Iyh�*����,�,���Nv�%�.�@��&���gH|�}x�/����N1���'�"����r�f���9Ke�3�OW�	��`=��ViJ+���R��$E�);N���OI��f,����P�fm=^(a��������N�K�Qf47�/��O0��a(w��$�=��*�gB��-����z,�_?3d��5���a���]J&��a���n��P<���l��Ix/x�xr�~�K�m���3�p���S���nI�Ea�-����m�����t��b��iI3R��f����R��i�����h]k$�3�RY��}W����X���1���"������dU�b�����?L!�G�X�J�Ygb]'q9;`PU�	�E�� �bP@=��MPsz$6fR���(s��'����%��tw�6p�xR��{Z����q'����)�����o�K���M�x;x��z��ujD���|�	#��_)�`��Mo�]���U�,�$����?���j��?�����?�eH<�TD,<�HD8���;�����y����{���d���F9���!	H88�5hC�pj�o�T�Z��A��d��[�$��K>��/^���4��8�����@kT�n&��R��u7AA.tz�%Eq2�W��
�-g�n��Cg%����kT�*�P�}�������q0�����������)'!�p��4����n���}�<�//'�%����):m)�T\�h�����9��������+��c����	yy3�����<8v	�����
���H������9-���
�[�IR���gQg���@Z�[�N��_�BSI�2���N?�6�����2k�P�����FC��5EY�4����
���9"0�5M�������N��������'����)|i�>d��U5�,���c2<0�)i%l����T�
N��L�G���=���6��}�!����
c��IFk������z1
�����J�9U6y_��~��s\����,�:k�4h�Y�����e��p�9��i��0]w�*�,���3��I���WY%�2��&��
f���[:����Mi����{��4�+UU*�0���l�?���@�?C��i`B)
�q<�{��.a	
IZ�*H"�]
��^q�E.�;�^�l���9���M��J��"�+���?�\�'�){��7�]��w������}��
��VN�D^��m#���j\��|iu
��s�@�=6��B	h����[�k�nn��eR.t�0F�Oo��e
9��^(F�>��Q��0aA��*m�&t�����:��;L�����O�pj��G��cx��@-�:
%6�I'���/W�_!>)�_�G|��p���,��6IY�j���>�FXd@]���	5O�oW9�w����W���5]%���{[N���cXp�������K�)���c��Q��cg��~�f��Q�g_������h������!�����H���QRuU��E�����qF����>�>)��_Lh���3Y�W���(��3�1U����j�d]B���'����O��EBJ.�o3m���"9H��@l�,���o�t3)3]� ����A
Xe[BL
�/���}���%+�H��g&��}:I�[���������N��I��K���,�M%�P��
[��B� t�R�[�%�Rv����.���,�t~���P���L���e�-_�>5��}u��.�W�QG�W�QG�W�QG�W�1����#���G�����4�z'��I
=��l��4�Z����g|�S�?_��'����%����#�����O���|uS2.�t�]E�-�|I>����|v���{������g�+>�7��!*�B�)z����p�f?��#a����f#���b%��������L1��Fu:�z����"N�G�t(3�yCoB��a/ed�����������_!�rP���7�nqA8�uU8�|w,
*������u�+������GDW��-�<�Ba�Ra�	�G35j�#��Kp[������.`�d�����m���c�1�I�s�U���-Gn[h��d���������[7<�e�I�������y��?�� ���`F�'�I�	�
�L���?�>�v�j�?<�������O��
F}��\��N�i4���V�i��\k��h��Q�Z����w�N���I���	Pe�L��42%�<�7��_�pr�\��!�Nox3��&|J��wG.oz�;�]y���)�����G��dA����x������o��������s2d�i��+��uF����%8����������=����A:W�C�d��a�\�����BI�7P\/Y�"E���mx��5�������^?E��@�-�z���zF�P�#P4�#�G�~���
�-=�,����7�h��&Mj1�x=�F=��%����,�������?�'
�
�����������W��/��5f�}�
��vq���������vK���Yk���6��U�M`�?���t(��[��x�ir'��������(��*q- %
K�y�eW�e���q�+;�M���J�$���#�]_����b��n���xy�������x�c��$�
a�����[e,_SKW�0��-iF>VT�U�Qe�W��QjuE�I���F+%5%3�E��4u�����p67o����3�3����]��jE��]�K�U��,;��ji��x���O�d���J��#��A\�
�S3z7�Tq�+��y�"�1q�8��m�o�$N���%O�M���2�]I��g���e ���`Y�XK�4V2��J��J3�I��"��P.FY���g��O�Rr��<��$�2k��4���A��������rV�m��,�� n@��Bha���pP�	��jc��+�p+aSq5VI�8�qc:��/W�o��D���-�fI�3k�J�T�8F�)/A+3��d�Mg6&�����Lg�2��T2YO\�=Y!����e���=���*N�����OJiRH�]
8�r1_mu�v�]
��|C�� #�"@���*u���=o��V�Z<��0)8�:/�t�Us�5�N���k�*W������a'�p��q��!c�X|7��UK$5:c����q����(
�'��*�V=�2���9h��������Y8������6��i�o��TV�,f]�����5A�a��
��_sn�n��s�n�
a���.����Y��5E@q
��a!4���'��������X��L�,$P�0�E�/�.�8��
�.��3mG��U���r���QP�B�!�7C��H�a�(�tdk"=E�*���N'J��������2\r���m%����+�-7%��yV+x' ,o�����3iq5�a�*�WdheKe4�F�%�A&�dt�(���\a��s�1��(�� 32�&wd8���G����cw_TB����Xy��o8����(s;vU�� ���6H����_��T\Z"XAB��YWa�R���#��W�f0��W
���T����;���BU�7%�[�AXa�	w{���ef�xJR^F���UZ���-�����j���d_d����S��H��o�H���������ya�cNd��]�8�FH�n!����?�����H�;��n�dQCxn�������I3����^q��3iER( �@�
QOo�:?1�@�*�/�P��@0�����j��M��6U�c���n��-��u,�
�[�Jk`��zK�8�<��^��A����x2M��k�tl u�b����+U��(���F�=�,�gSS���-�����q2~���Wa
?�c�o��[d%�Z��HDr)��pK\��XY�l�(F�pX���B�>�%�hi������w}
'��d|
�E����7W��z������N[�:q���G���X���Z���V����uqJ�r5};���o8�B��������?���-����7�I�p���%�M���s�$r��}���������lnOx��+%����a�
���5���yM��f}N`G�3m6g2�]y��[�;�i�N
������fN�0<��~���bM�R�|G���,8�5���'������Gv\�1?��l������O�X���hy���<��R�q[Y��h��\!�X�h'�`$�d�����r�����r��ldcF��[i\��	��w�n$�=4T���1���V��s�����X�@�* �Q���D(��L
�����8��������u'����2v�.��H��������S��[�v��6����*�Lcb}�Ps@���!���17?H��B��	a���p1%�~������8�LlJ�n�t�
��*.���f�/+�`�vA���p����m#�K��d���_�{������t�i���@���4l�������cU�i���KP�����y����Q����~����E��uC��6H7���� NN�:6$�P��A���n���o��u��7�����[V2E3�*���<���O��U��6H�8��z�������Bh�s��WA>?FD�K�P�����������@����~�t�u��|G��w�����oI��^���*�E�'�R@H������$����$��)��R���TD���?\e��*8�J�B����`W+����J��;�V���S��x�z?���u���z�Uw��zI�3������U��~JQ2B���#�g; 6�v	��2Y���xz�<��4�6�z���Rm�n���r��?n��+[D}kuM�s���QFH&RC�z��@Y��x���j��<m������Y�Y�����8�9�0;�c����6$U�����3�5kJ�f&���J+������k���������_x7�Yr���pbX���������J�Pf��*��<@��o�4p�����\k�6g��o�"do#p��]�(�F���`

�U��O��w��/G����_As��Mg��n5[�v��zM�ln��#�rm�t�D�Z%v���]�����7�Vg�����j�9b���2�x�U�,�!���|��_G�w���8��))qd�,8���c=�0�C�}U��I��F�$���� u&�U�����=
��.����Sq����[��\����O�p~e��2�_�����t`�gd7�GQ�44�����7%I:�T��*%�nM�5��_A&��������$nD�
b����5�2w�k�%C'
�������nE������$���51�Dz�4�����|6�[0-#�a>���,.���������X���K���+����	����_'��=X���5�M�\���Z�5�2�����cl���X�q��mb=
�*������D�+T����W�/��|����:_�� �'�|���Q�M�8S��O@o#+������-OE��9��Y�_��B������`IQ	�0n~X���	���o�:���#��w\y���
���}�4��}���hE�0�q1�Lg�����X�T��RU&QH�2��"Ye���TD���2T
������otef<0�<��'!������we��A[>��O}�[*g�tw�km^�53>�-c�^�n9.��Ma���`��������$N)���fo��<8|���������������l5�w3��V/s�n�*A)m��e[������M�������a�z/���rU|�����/�y�by��A$�1mAh�~���Q���R��������a�������$�t-��D
Y��vzr1��T��`(yx�������KC"����x�V�,/���s���A��b��@D�_7Nm9��o��3H��D8%7R-s����0y�}t�!�G�6zp�w~���v'�n"�q���8���)���Fzg}���=c���{o:���D��)�N��aQ6��Bk�ZJp�
�r]��X��,L��\�E�����c�\�+%�=���V���j�
6�R$
�Y2� jJ"����B2p�5K���
A�[��Ai�������~�-Yy�
����� n��6'������F7W>Bs���2�V
�$�&�4J�Z�����Z�Y��Q���������Y������r��X3�io�4��������Ar�(�R	��R�[�e�V@6�0/<��{���M����nf��������G��E[�x�v��;������}���)Y��1����0�p�@���py%�t m�%�8#D��1�f�����L��3�D��L���4�����%V
|v#������YV��z�^�Vn*��od�h1�?�hmdk�fM�����nfh�H�s����)I���,�`B����%8'8����Hp��l��0{d�0}��)0Q��AH�	Z^I{	��v�������~��`�?�Ro����5��k7��B��� �eR���������(
�$r��(��|P������%�F}2��]��,���!~�2�6�3p�@$N��M�X�	[v��Z�����9����k6�z�9�M��a2% ��QK-B~�=����1��p�����m�s��b�x�`{/s�7�r������2�Pk���q��G~E�����# ����`���k�,xm���T$G�C4z�*��xL��X�$���h���hz��Ji��c��� �2�%�!i�3Iz�Q?��v���r�7,���	[8l��\j��TI���Q�E�<�"����LQ-x7���	V4(������{B��H����N�5������Qa�`?����>$G����|�^�B�h^eP�n�5�8�,nlC3	<<���������-�4vkp1����[��%���f������d\�t���	�%��k�*����)�Q(��M���}[����'%@�=��iv�#G2-J���u�$����@����0�IkVyE���+X�@E�SDI\���f���K�:N���]#H[�����&�!�>nYm>�f�"�n�8����e�V����e�!� ��Z�
��:
�+��uV��1�8�l��Pp]3<e���E��2{M������s�����D�?Om<�cP@]������r��
H���Y��U�Bp�M�u'��Nx`d����>���?f7��`tl�����g��@~����v�������L������3����������$4�:*�9\J��wv����?����������]<�t����������n3��&��
�F����?���1*?R"(��������o�??�8n��>fd*
6 ^��1��s�3��<����O&�����^���Z%u_��g�e\j>9S�p��t&�I�S=��-o��0.���4�������,#-z
�H�������p{��t6�z1�+j�n��!p��G*E`��v
,�:@�c���F�8��Z�8G������Z��>;?vv~"�T�{������Ti
�F�����1 U������������&���K�)��X����"V��s~j?�7�`Aw�|�D��-�0�/�sZ$��v����Jkd�\_���ox=�M��B�j>���'u�G7��B"�P���i_���x��J�{C�f�3O����xr����)�������;������+�����!�:�_������Kv�f�^�;�j��'�p������f�I�� �&�����[[��22�"������1�Mq`��lY�� ��,C'G������8��48���>�fP�Q�����$���G�QKx� �l.�����t���5(�
�'�t�bjv����YNY��C�}���.���`����B��b�'�aXJ��]5p���SK�+sn{�omt
�_�;��B�����v�.R��9Nm��!�/�)�+��;#BN������>}dU88������=^*R�	o�Hq��|�U3�p3�h�G^x4������R��ZI���D����ul��fj���]P���
����XU5���y��3L�{��������wv��K���VW���6�����*~l��Q������9`8��-�;O���
�1_�FW�Oc�	��Q1p�����Y]������A���fX��3\�fM�n��H�r�`�mkf{Zq�V^C�-�W��6��Q��_5��y����i���7U�o#��0��U�fZ��4w��]+S�b��
�f[��e��*E.�U����Qu~���A�U;j�s�O!`����YU��a�G��Mh��%���4hms4D���Zh+�\�j�E��A&e}%�d[���q��DCqP����n���	��$	�u�$R�U�����2yjD]8�t���8?���@�P����Pz�e%/�;�(7�5"�����m��t�&�v��~�D��Vt��	��"��?�!��)�z�A������Y q�BsCh�,�Ty`������Q>�N��T�_O��������(��t�d�7HA�T9���tJnx��*V��/�0�1�������xr-��G�Q��	�S�8,�S�R�t��b'L�����N����GQU? ��f�Q��8�����x��x�C�����e��n�`�����t�����6[����{5��x������"�b��|'</dc5Bl:��@��LaV5����v���<���+�j�X�]�`��a���V���V53�L�2\5��q5#<���6���:7�b��vm��v��lZ�S��F�P�>�g�.�g7g8��U<�n������"z`e
����������?���j���]����|�=��R#{&�L
�i�	�9�%�L�gO,{&09�{�V�#�T��;�g"�l1>�s��>x��n�0�����]�@�Y�����3s���9��PL��)�8����x�<!?uu�����
��P1S��$6lBw��(��]��X�y"���#�gZ#e�����3^3[��nA�?��d���]dP���O�[H�,P��� ��tA(
a��Y�2'"P��
�?�bvA>���{J�,�y�r��!=kY�x��
����+\��|!:� 3���?mp������"Z���s��*��5��de
����R(�/9�fw�h����*[T�M;Pyn��g����"����`�/gfSS�>����UhM]m����m�i���i�:B^
0{������fVmU�>bfb5�h�� bf&��w���7lfr��������nJ���z��3��9g��t�s�L�6v��7w�����u��n�4��������C��)�fwQ4�9�hvG�[h M��ISU�BBiv���$���� &�����7���c����Bjv���m�jvsG��Z����t-&�f�>�f7��
����	�!g1�3�64��)$vf����.8zf7s��n����:N�JI4
U�Bh�zs�M	���7-�f��0���9���������U���C�LS����7�CY��P,
r-���tL
�����0Z�>��+:�~����T�@P�9���bY}�e6&��.���������������Zy���9x�2����J�L�_�a3��t! #��R����g1�kQ6q[#[�u�����h�VW[�f�2b�m�V%Jk�F=���uy��;���Q�i��~�>�>)Y��^�3�h����CB�_c�h�7g�(Yx�������i�g��h��V����X������j!����^j5�T����O"��m-VEwt���KWF+/SA�R�4
NS6C1-�P���!�n��G�@�h��z��k���=J��������tv���t��|zZ��-���6Oo�}[?�������6W�C?��{C��
���V�������8�����`��r4������}2���o@�o}2���?��R(���RrJ�|�8��~N{���/�.�����vbs����<')�msK,;����v�e'�F$R�|I?�%�3��M4���B+'����R�4!K�#��_��-��x��.��;)�t�	�t�Us\ec� @lrP��G�o��+��!��	�+�d:�b�_=��!��=7������_x|���s�2!�����
�F���\bc5�\�<���6sV�5s6Z�
��D��o`E�����R���z�M�'�<�f���K����$��_O���h0�Kr��R��^s�]�k7�����_�p�#p\�HIh��u�6Z�8�/-5�����W���w{��#|�Rw0�&w���?�
�C�|������%n6�8g5r=�(i�Y����9�@�\N�znv�EP�����p���&�;q��\�L��I�tof�E�:z�����[r1��y�'Fj�N
9�D5-
m`������	�m�����d<��9dJ��bD���}�!�]z��.3�1��F�,I����"�F�x��V������a�����D���/"�="��69y_G[(�\�!��U�Lpu�a��2CUh�����7�/7����������s��
J{�E_*��3(�XL����	���O0p���EXX�MJg;���
K�O���M�H������R�uR�e/s�y���5�~��F4e
�����
�T88��V�L-(��6���c�K%,g#�D�_;'�I0����kD����4e5%Q���2�-J��'�����{�8;���������� ���=����GOj�=a����<�;H��D�b��J���6���\��}��'+v�`SPj�v$�������Bl�&��$t��t�g��J�Y�|��/
�8�C�I����1�����=g��S��������������P#8�sT�����,0/8HFa��������t��N��"�@fT��v�;3=��Lf�n(S��Di2e10y%f��LT�v�Fdn��eLj	�h��378i�A0:g��Ou��36]�$��+���P�:?FW&+L{���v�T-
I;S���]�yZ���iZ���Y���y�
������x�a�	;zB�D8z�]���R��iY����Z1
X�:�1*^���V'��4�cC��d���#E&�#��d,�^������Z-V������H�<JY�|s*5Rv�ln��]a�
�����3����v��e�����UkKY�	�N=����	�z���]w3������
�����#����Q%����F��j�D�Ap^�Z���FXu��B_fIM�|�1���#�1a�����Q@:+4f��*x�6"y�9��I>���|������5���6�%��0IH�Q�f��/��Z"7�]oF��Sc��"��M!K�1�$��J��>��n�@h����1�Yf��@�sj1�k���R4�Kh[��V�]
��v�������+��r�3$��><�{&������H�HnG�V��4�7�X~����Uc���L1�������aC��-qc �H�7*�&�4�"h���X_�4d�r�RD�`@4���F2��y�����)d�#�b������R����8��G�����	��j����]��'AA���B��H��tn	K7_��"I;��4�|Mc�2_	���D����d�w�����p���
e�������H���`F��C�$���n�L=w�{�����|� t���14��--q��K����'�Q�];��z�^2�Bjdf�t���<j�J��wa��k�c��+����2�������C�J���C����N����a�Lc'�,��nj����(X1T�]�����9�����R�
zU��t�q��<�<����7�zAd��/������6�J)!k�N��=����<�i,N��s�Q1m-q����[Y�<���L8f����Ti����T���~S���1/������(&���`m	����p���E�$~�y�� �/	�)��� ��}��(����]��������������Yz��Y�U�6���
�`�L� ��&5�Dhe�)��B�0O�(E��92��o�l�GC>�-��F��o�l����h��F=�Jj��J��(LQe��*���X8��o�n��9)��>�����Wi[K��������P����W����\�`qV�����(����T� 5�	�J	�L{����b0�)��$�p���"t����,(�f,%b�<i��j.����b|C���st�������%��������1m@�Iq�'���J�����������X�(�W���Hw����H�u��j�}Y�{t����7�/�������Z���7�P����1K��������GU��;���o�n�]�'+Lx4��lB{b�nc�������G�<���w��I}M;�I��
�}O��H�_�Qo���b:�~O�x�Oo�R���v�����7�eo�����u&HV	D��IQ���b�� � �I(��
U\��|�_��;��G����O����4��z��m�7����FQ���	
0002-JSON_TABLE-v39.patch.gzapplication/gzip; name=0002-JSON_TABLE-v39.patch.gzDownload
����]0002-JSON_TABLE-v39.patch�<kw�����_��=3�A��;��XN�`�N&�wG��Q��D������n�[g&>	]uWW��[�9�����i69_�ju�ujZ��yse.����0�����[����l�w��b��5�cZ�R=�6�lh}�<��Z�?}�?�l���=����]��������������k65����Q�T;�R�����
+Vj���t���M�����;��f������t4���7����������s����q�z�G|����h*����1�O���W�����+��l�����_wk��^�	��x��_���l�n��;GA����#S�����]����[{�g�b���[�5�H��Pk���.�u��B
� ����,U����������R����{&��W��]��R�{/��y]u����j��$�����G����T�#B�Cr��K%9]�����<���fG����F<S���f�(�6<�N.��Z>�g8��St�(��{�Z�W���������}��f'����c���b�����)���q�[[s�_r����f�'Lju���
M��>�D>aCMHb���v'\�	R��d?H�U�����O_���e�W)1/���)���z��9��$����Kb0w�X��+�'�����[��)���Q���`����56������,�l�K+�&G�����.3?�G�,�F��d��	��[(���&.����������Z���G�c��s�����v����T��J��Z4Z���U+�f��^���8��GO~��]�*Z���+�6h{�����_�=���:EBv�����
��s~�NNN������2v��=�+���s�d/N�iI�������M!��|�������l#=�;�^�&���������y����H�Y�yd�����>�F?Q�i����$�����y�\�u\+Dc�R���jQ���e^[j�]���B� 	���J-�(�vP�t�����ua�6���%�����,�xR��{�#,��)Du���uq���{�������t
�={0��jS��56����fM�u&&6$n�����xk������l��������`���,c�u�0���G�
���H�!t���Zo����B�����0��T�u��UAg�u�W�:���Vj�Vmk%pxtm	��fky�4�f�����8RM���������<�66�?��7�/�`u�F�����(��,H�#��K��`8�hs�Wh�dC����Gi�&��#vqe�]�"�R�4p�9g��r���������<��L��'�_�j|U7ej�V�������J��*���&�]U�A0o`����g�vHzR��<�X�],�(H�j(I��_w��G�9N�u�a��p�nx�������{a�.,w�lt��w������1\��j�F(G7�����>���]�8��m���"tQ�����V��������QZ+V�����%�Gq�7�����^/����*�Vm����3�`�������?W��"���b��~�(�XT��!DY�.��Dw�sz(1���@���7�5R�F�R�V�F=�l�z|�.���9i}�S��
L�+��| �
�~�A��<,��b�\��i�!K�5)�%_��'�����>��&%v��:����� ��?W�2K��w���Y�}������<KC[Ua%cy+P�]Yj�z��*�WK�]��G����B'GS�0��\y��?eZ���B\��*O��`-s���b5
������1[�7Y�t�3��#����j�����%kEq*��.����D)A��T�k�	k~H�[@7|#�* DF���Rmjh��FdA�'�{��� Fag�&���x�%)���wn�t�T������;��F*I����6���X�Y.s������2��
����jk�v���7k�D4��Oq��:R����g=��|
Zo������(�����O��{s3��"%��8�h����ga������4t�k��rO���/���bv�$�v�n�����P1g�2�`�j"�����6�d0RJ:�/_B����;�YH[���}�f�X��!���8��{8�d+�D�1��M`Z���0�H�TF�M�`z���4�L?zI>�ww��p���HgA9�I�;�	
�����NQ��mw�����;��������},�����$�[p��=;?�D;����rG���)���U<����/1��	����x�	��*�Rd�������h���cm4x!��F-����`��1��~�M��=0=���"��������b�h5��r����F#;vHsHi�G�
� t%3G���`x0�����7`;���m�|h&��1
���(��F���i�;�N�w}}p[���<D�@at�,Z&50���Vqd0��,�9�_P
�'vE�O����@�l���+���?���������"Rs@��$m;KkN�{���8�Q�;���X��ht�~�5�:U+/�:�����
�`�)����v[�`�a��H��&�e���n1�@�!�VDSiU�d=�Vz6�rz�0�
>
��s�����t~�����3)��7lV��G����E*�����U��ayB8QQ�������&��+_�a}+��4�0F����f8�:n�lgcx�/����.jo,o����x���T ����{:R��&U��t����uRM�5�$S�"�� c�n���E5O(H���R���N��j&D��EM5U}����XJ�*�D���eF�s��"�������
�`�}.����I�Z�5�9��HOC����j"by3A�����<*���q�9���	�A�r��N!������<e�"d+���"E�z���E�Qo�4��E���7���(�������{|���c"�k��������
�&��T�������	V"��,��,���e$=�Q��L�2#�|�`��3-�Ql#Z��7����i�Bde'��M�E��|z(��KS�>Q�b�k�U������p#g�X�"+��!Q
�U(���H�c�g7pD(���]%�lZ��K[��$��EN0��-(oC�p?�N��\L`d�c*p4#K��IYE�d2%�������TH�TKOdk*�D�&P�l)>��M1/��M�J���6�]�Z�����\���`��%`��.��TI(�>��2��Eb�pa�%�d�������H$Ol�Fi���9��)���
��%���lq�G&l�!����$U��Z��Z�ZE=��j�RUCE��������xV�LJ<Z����B�C�\!��w{�lJs�k.5z`[��"p�P;�U����em�2Wf�1�4�,�A�h��
^��"��LD���C������t4��m2]��`�,�%%��=a���g�2�}$h"
�����Bd�������'���/�_q?��������C����e�`3�����oF��~�B@���'��EHT�&�W/�����Z"k�5����1�m�F�<�5}k��+a�MX����\&�	�`:�������(!�]Z�wT���5���Vge�����l�[��D�C�������
�Stm���.����������Bx��?K3����D�E#�P���8?WQ��~��.���qng���v��p�tZ�&����7{�Q�b����L/�8�m��
�Hu{����GA~X����BQ�d�3hCA�$nj�������P�&�	Uj�R��%8����k���R�?���b�.>�!��J����)�����\@���T�=���3R���d��e�����Fg�O.��=s�@�W������������Yo>��3����3�r�N�(��j��k:&��a
Y��G:���}��1���vm�04�|�m�4�8d�#��|��JM*5��a>'�����
������{r���g2���������������>Q!(�,g~� �.].P�bA
�(T��VP�����t�9�:�
%��U�X�@�����@�GP��p�Y9e�oB�-q�
�2"��;|i�<7C�
���oF����~k����O��=�7�e���$����<)����
z8�)����{�Mg2�MK��0���������u�����HQA��h���T4�; ����aYMse�R'��#�&�������0��z{��XWf����q�"@��k
YEa�O��G���N�� ;d!��0�8XG8�Z��<S5��L��*���=�3��M�Z.���Xh��,�����n-y�(�,������������z�i�'z���`�:�D�#�!�fxC,t�I`�6*8�b�R��P9����S`�^J��9<������G�<LPn��^m���V)�j����b��
�B�3e���l��Rp$����
��|D��I	>p?B�Y�'!���Q@�ZvL81g��]�N��Oz�;9���$N�r9��0Y<
��[mQ��J�N(Z������Ux���T*��_����WR0�[�@c�t�?e"�-8���H��@��g%Vm��r�{��m�GM�YY����s��Q
�Ooh�D�0��'&_y~������~*�4�_g�r���`������p,�a����lT����4W��=�8u�����B�j_:����
+�n�����Z��������o_�����C����� �v�����^������G�?B\>�@�����D��1����q�I:ke	+s����T�\$�s�������F�l����1������n����T?�2�w^��a��3�����/����g��q��Y�m&��1
i�JNBhJ�:�X�yJC�}��?Qy��#"/M������.t3W�r�$�j8��F��Kknl��t���c�(�|@��3_<E;Lk_����wJ���Y��Pa��L�
�^����!_�	�R���@\���`3%d���>3�/���er����H���C��[�q�c�DolTi��ruFsI�e�A���W�z�f�#�i��N�����K�J�~�ik���FUd%A�r����D�3$D����j���)*jR�*�
,\Q�>����	p�j���%�X����
+���Rni�WVl5*?L!!��'S�7ct��;��|���OX
���2���a*3������A��I�}�������������~t�����j���>���5�$O��wC#(������O�C���Urk�0���!_C��(��O}������������^������a���x#���p�[Gouz�n��G,�L��
�7��^w'l�������p��(���h�'E�N�#�6{�c�k��=^h���w���~S����p3��{s�z�*���a�:���J�g���g�m�^6z�Aw�S�������c�O��{�N��8���!?'$�q$5�n�@�L����qw:EJ���������Aw8e����{s�=����1vq��d<�J����ix���6x�[o�T����}wB&������W�$���z��zxG�W��=?�@�UO�yjT�j7~���|�������y�0�=o�[z-�Zrc
��������&$�x@d�p�/!r��pY�V��(y5��G���~�}�d�������W��"��������]w0�����a��s:�< @�@�i1����0�G�Fz.F�Jm��"�1T�Iw�Jg���){5=��M���x�{�A�����Ok��������cI�3����1�-lf���f�����=�8�r�D$��^���]K�}��@�NrxK�������k�.-_������	��R��5X�v,jGW�����x
�sy�I.T5&ajieuE����l�@o,�7�K�X\_�f�oIr%�_Z�^��dG(('��BW� ���������u,���A�;�I����,�n��K &�",��IV�<`W��� ��G6
���1��L�g��~������xcut��oH����	u��=^R�?��#�f�B������k�b�x"�7{u�>�9(���uN�����L7l9$����8Q%$T ���5�X�*z0u�������`^��x��a���j�������@D��o����r? ��|���!k+�����
�Y�;$��xrM��S�r�e�M��o��U���$���|dZq�f�"b����C��8�@�4����v�Py��;�c~��"hmnll1���~TL-��]�����*���j�.D�p|\����wku�
�Hj�z%����	y��z������5�h�^����Y���%���JCI��Sip\�4�S�=f1�+�Br\�[���|N����t��,�_��
�TVRiE\W���RdS:bO�P��S��W'�p�2���7�Rd�oY�������hhN|OI�%-�bM����		9��)�+2z��Ro����:Ti�:���m��c����Rn7 4��>$�jT��(�L��|i��O�A�SJ��9���o$��@��2��hpx.YP���������	��������d-��U�����-p���=iP.@�n��e��N�(�.yr����'3 �T]N���k+X���Z|�
Kj-,}p�4R���X��H-lBi�8��
���w	��u[$��hK��M}�-�\��EMs%�m��xS�q��^��:��XQC�����+���d1�Y�N'3��F��)>f.��K���A�P������-+k��qj��pj�To��#�:�p8%+CN|G�T�����nL�������mXPe�����:���)���W�g���?}y�T)����-E\�����l����X��4���:2��k�@�~�x��s��u2�[���d����p�(W���4O���FD��m�w�(]�~bOG)�lg9��r�2��X��{Cb*ov
�O�3��{q��C9��Q���7o]7C.�H��E������������q-�y���)�or|8����@\^M�7��X�]ELCz��C������6���_���� T��ozz���)��H8R���?���}���5�N=��Kgk�x"��m�@��@@	@[�;s`�GG�6�{`����u�p!��P�Y�o�'$^�#�������3���;�QW6@�����~\�LN������8�����C��C"����1��~��E�4K�}�Y'�z��v��q�M�c���z����H��Q>s�j>��)o�K)>
��f�
v+ ���"����v�����R+�?W#9���(:��u���Z�I��>��9��8��'�9k�4\�x���#����,���W9���i��prp�����u�������m�4�ucK��cy�z+�#�%������1�m�+��X?Ny���?�o?�������]���^������7��[�@��@o��U%U�B�w��?�c?�,���=�x��&_}�����R�
S@9�JDE,���*�JY���`�T�U�fx�4���nhk��=���Z�����&�J�q�W����dU~�7�Ha�� �����A����p�H7�r��9NPdU^�T���lU���=�������I$I� ��0��{u�x{{@d?�C��2A?�X���Gu�KX�C���C��`,.�/@�����������3u���Q�><��X�N�]C(�p�?^��	f=�>�e5"�`�*�U��!B�(��Q��
��)��94�%x����t��$�_�����
�n�(W�������z��~t�������c�����������d{^��Z�?�}7z���^���2�����b(]R�a�8W#H/����>��&����G���b���jLL���Z�@b>GW��e��j'ue]4�����!zk�s����~6-���`�'`���n��U�	X+���0,E W;�|?���U�M-��S�����4\�.�4�Qkc����4f���������q��{W*@K��pZ�����,w�2�����f�H3��[�L
�E��j��5�=G����]$CP~�'++j���:�@���&Q5�e�|;��������##��>�
eh���H}�ZK.��^*�X����N0��������S�����6��f�-,�]�8�
<��M�����=���d�����zS���(D�<;x>����V���x8F�%�mI���r �f:��������`�u���w�/����e�c���\���eP�4*�(X�4�:;z3�*�K��{lM������b�a�u�xx�n�
K���e���p.�*����}��oc5t]E)�h��S0~�D<���_�ru��L:�z ���@�:Y?�Z�_��w:��<��q�����������J_�,�
������C��;
�`������r.�Z���F��L��8�\4$�d�4��X��%,��E\"A�r�,�]{V"(���K&��_�-�#aW�VUc,���Sw����5�t��p����F�J��z�����������%~���V8F�q���=mcq���������Hm����=�������\���\%���2q
�M�7=�w.��?��R�������s�u���"<b�g�����R_	&A��s5L�T��$����=6�����W��Dn�2?M������q"/�����M����{�@"O��J������MEz�����[aop�/�O���>��Z�_rW����L�aG��!rZ�7�u�$#�J�r�1�@
/;�@D��2��0�:8��bA�T���K��9h��8�?U�Z��\u�8����I�tlU-yr���4�&�-�HC�#����.�K��%Lf#yUlG�c���A
K?��0�����'�����]��� �f���s�7�H��4��?5!����/�����E/�g]��Gr��[��\����f�6��>Dx@�;�Nn��'����Hbx1d�"b8��5m��U�^%����5/.�^Z�F;��_�_�T",7���M�:�����92��9�*&�%#��"3��}U��\]u6�!9��$�����VC���E4Ry�K*a<	���.��1�����	�V��m
B��@���]����5������M�����rG��O<�&1�L�E�Qj�=Au,P��v��q���.��vN?*j=��o-��G\��B��bmk���k����Y��F�i��+�f@/�<�%�Vu�9�XbkhU��d��[w�:4��=��m�N�a��`��������)�H�
�B
�H�v>��������6�L��{-<�&d�jm&�wf�����dr�(��90�|2�-:hU+8����T��m����ATy���&����[��!�0w\��<#K���'->Mka=�	0���J$��
@�����9�,'"AXln����E�����x(������������f	��x��nkN�V��2&�bfi�qi�$�.��S�*����y���$T�(���a�9y���E���^mh��W��9G�^7�U��f����5(��Q�"gM,��W*�;���������B�1Ba'�����\�A���I<-���fb/�D���6����*�����ZC����6�{����b���G|+�N��X���o�WF���Jx�{��!�
�"��3��=}��j=�F%���"b���/�pm}��}"�%>�ZnK����~*1eo�99r
Y(S���l 0��4������/��=r�f�X��cI"H��btN�bio�j�x+��{c�B:����~���-I�-����0F�~+�]JO��Pe,�#j1�'���c���_�J G�/�'c��P��R�n*i�=��
e�=�Y��+z���:T�J��0J���.��i�H��-O��t�1���8%g�5���#�X��'B�f���v>`s@��4B{�&$xL�=5�S��x"��p=�Y>9��3n�.��BC�6��xW��G�B�^�X��)3*����<��m� f��$d�����gU(�m<x^;X�NE�m]��}�*@Ga�����-��%��&��PN�G�������k]�'��C���H��:���n������d�������z�2��������)�%F@�$s�H��X�"���Sy�������s#�0��nr���o��s�<��D�OX��xB��E���\Kh���r�-���m�+
3EU���������5�f��H��dD>��XV����^�,����._���Q���x[(�%#r+��y7$`J����K��
���,s6j`Z9�_�X4��]���}���f(W'��eO;��d���,B���(�\��Ga����o;��	%?��\9n�6&r\���w�D�����:EW���i��	�#J���K�(�{t�oD��=���br=N��@������1g���dO�.Yo����gl��ZW�F��6)V�y��������Y�f��p���i�%��Y������T!"M�a= ���	��t(��*fC�bsp������_��1�VD[��-��2��1������S�zXy�;��<�;@)xx���a+�2�e�tB�y�uJE��H���Z!sl�3�H�~b+.n�Z"��e��Irx���g&&�D�)�+%�s�a���A��W�;fA��Jo�����������"�}i_H�l��H#�!J���c������\Q�@�=,���8g���(�bX.��%O�X�3@�U03��u�}`<-X���������G�Z�O�hAD<06�V��_uA�[,�����:U����Y����\B��X`-�X@7�{�
Bo")�9�E�FLE��G�`�*@�X��[����A��9c�h���U&NE�x�&�AH�?���*��L�Nn��� 7�-�k�2�����L�C
��
�������L;����ba����Q'(�@/"�1���9"����2��$cz�L�c���V�Q��y���+���I�F)������A6���5���~P&'"�L�I�tr�A�j-;����g�q��t�������jy�=3Y�)��'�g���eYM�R�[e+��IC���}O��)�	��E�:�h6]��$����������~
_�0���L����i��c<bM���qyb������������Dd�)x>���L�[����8��M��"��������^��
�?ye���X���������|t>.:��l�mJNyu���-��}�v�d�gg0�!��+�%]�
4�����ZQR�P��BY��l��J�C�H�1��$E'N�Ge,����}�@�Rl��<������22�/�d.�\�D����<Q Y���S�!E������Ed�kSy+�b7UY	+u��sh/��,Ad0�pl�
�� ��)������w��������-/���^�o&�s=���/�o��u����"
I���3�����R\��'u��'��p����)2�O{��b��+�5g��c�q�,�9M��3�#d�X�Q�{��+>)Y�6]��WRGB��M�����v�gj�K�=�����K\A�M�+��_���4.�� ���d��Z��p94�
�����y465��q>�b����k5�0�J�{�~�R�z�B$��AB*�"����Z;���t�!��esr �
^�����F���J�s�q�c�8��Q)����"dEg���x4��4|����tt>���!��i���SV���as{v
p���z*��Cg%N;EJ��=X�A7.x���)���t�����4�����
?����OW��� �|6*��v-��e'��c[�p"�P���$~����%��������sh(r����p�(���E���	���D�4h�(��<P>�"�����U��8OK�� �j�xFa8
K'1���t>�3���	�-��U�hG��qk��@�����H�gb�^}8�0ye����u��V����}��X�������Y�rP@Y�{�hP%���5��|�.��
�<%��V�D�C�r�@Ln�QO��/�<���>( H��6o�?AK�[YQ��d����o�$��.�B�A��N�$�	�$������������In�I�\���w=��
������1��lD���yPH��uL��2D����)��m!���J�HG��*&#�G*�;i�m�H�ZI5d���<�$h��
f�����bu�WX��Wm��O������t���3�-(�����'�e��"[]��3��$�W��
��-������O�� 0�A��X�}����	���o��������DL����+���AM_�L�^���B�b���z���y �.5�0��(0[5�AT7�f����e6�Mi��N3^nBvD/Q���~�L��|
rr�y��G
]���,�E(�9	�>`]�(H����V)�A_�8��U�V���D�����~Pd�����IOfY����k2b85�%� ,�j�����ZH��f�{U���{���
�F���hl��D<	lFG��
3 ve�P�}Cy.90�DD^Sd�l����YS�5Y�
$EQ0,���?�;P�I��D��p3$�&Vm@:	TD�l�6�����B:/�tS�&�W;��j��8�q�a�l�J��,�:6|����]J�c������:��5����z�_��ug�������~����7U�(�V&�k�.n��h>��8�@T�G�\����E���K��a����&�.�'I!���D�M�f���,"�T������@-�U��b�'y�F�hC�H{��/4.��{h1$i�hD�i'S(zO[�d�}]�&�"��`��3��>&�i�d
:��a�;����S�;�g�������]�W1�^���
�Wip`�o�%p������������K�7��I���t�J�����Zo�Y__o6����VN������\
�Mnn@@�U���`��	��#�v��M�Abtk��P�n <.,�z�s�����p�y����l` >�&��z����\(�+����I��#2��f�Zk@�Kc1uZxi��h�@��
PX�� �L��gU�p!I���U�����_���3)��I������E���T����Bv?|k���J`X��9=	f��[������h_UKY����R����Da2��L��MH�R|bG��M`T��D�������
�,G�M`![�
����)?�~C����V�),����+���}�/�KT%������F�Z;s��E�w(�����)��S��\"����v�w�hl�<��vfPVI���k�?�G��+E�A��������J���>d�b����Z���I���;���f=�V%������
�W:�:��M7�o��L	Y�}h��WR�M��%���������E2��U��'��6vz�����y�����=�����!��n�m>1������DT�A<�w��Qy�3� �8D�H�
`����������Tl��*PD-�[��R���h��M!�����\���}>}�U���I7X��r�#���7;�������V�M_�����K/��U��jb>���v4.	o{0�xtuaTo=_�V�)��s��z:?�/@������W}/u��3@�]�y���I�}~�z]��#�����}�\$���Qg�����{;<�GkA����y}�a��p��l�����M���
�p�� #���Cg�2s-mJ�\��A�er�_�$�Ipy�}��;q�\������.�-��L��W����*���@'}�����'
�]um�
����SZK{�;����K�}>�/���:����Q&��W���WM'��dJ?���������h��CR��������z/��s(u��4���M.N�__��D� ��S�N��+j�J�|=V���%��a�KN��V�V�0I�^�Im���'�#=SJ�����(`5��*������j`�l�u���{�����k�������.�	xU�ml���'NY���
P����O�'�G�J�>���o��!�+Q\E 0�������������>]j�v����mh?W,	Z���E
�4<�p&��$���\��m��2Y�����RX���(+(A��^<����������		�l�'��9�(��D����z�+�2~D�
���L�N����$N��b,zs�,���'�����N-�����|5���4�V��@J
�c���&��:
��@���dj9�o�����(�\�hK���pA����x���=��a!��I��8�g��o&}���}�u�e6*��A�.z����\X��Y#��&�c����u��`�y�H���?.E����k(y�4���E��\]O^�a���������� �
'��Y�����%�����]e��r�@%�"r:�p�G
LOq�j	��Z@�%������(�<�+���g�[��2��0����bsp��NC�����C��:�F}gC=�wkM����		���!�|����������}ni�b���i�h��_��{�
5���_~[�v�U}"�o�lV�rmonW��(�U�Av@F:�/hR���(�����bhS��/I��r���#�9Y'��(����?�54�(i�7l�?p����q�-�'�H'm6�^(FYC��F�ax
Wn,Q������tO��?����������l!�}�,+��u�r-6=�����V���m��Dt�x�A)J�;�[����o�n�7=���'��U�w�k���Xe�[�FH�/��,h���^�(�kC�����8Z�E��(8�Vw��O;�:2!vbyJYd��O���!D��E�f����-�an.�a+g{������!4X��:B����wP��ec��F��)�.WLM��
��C�0+��?�����'K���K�z�_�����������-@o����S�gV�W#���=n�!�)\E$�@��S�|��-����
"���S��c��\��}364{�}��vR��LZ]%'2S'��������O�e��#��xe_",n$�5B����V�4<@k���2�$�t�	���}���Q�����;�R�w*��|U4K�s��!c]y�\�EJ��t2����S6�HCxI����o��"�B*b��D������7���(��JD�%������T��K�V���	�l��{=�c<��f�y�/��I�$���.W�Q7�LF����X?Y�������c���>���`��d�~�����6{I�lP�a�V��2�u=@Ju�}W0n��4d����PM�oV�����9(�@���K�=Hz��I�ytA^0Y��J�C����VrX�3�nh�e ��d���{Z8Q:#�.��h�>o��0��HL���zV� v�D���0^`�PeL��S�#���������rt����zU4����LT����'i��������W�JnMR'�|��(lk�3H��&NI�	��I��k��L�c��)1h��&�FT�G&c���T��������,-�nQ.?���I��i��x���dW��@�h�=�"j=3�l��EQ��*�������`��l��`ly����O�����0*�{���O��>�p#h�p�Q�N3�s&S��O>�i����;��'�������N�����|�9����;�[{#1��$�3�W�-�s��\����B6?��M���W���6L�Y#5RM9X��S~@�/B��/Yx����C]��W�����^�lA�����Lb�H
C�w���L6��P�P��Hf�V|�=r������4g����+�9�x��/���#�t������q)g$8����C�\��Q��T8E�ng��<y�ep�i��%����-���:o�%`��c��P�1��Q�v�����\��4��iR�5��U2>�`� E2�2e��Xlf��I�P"J�t@pE�-��1r ��;�M��6p�Or!B��s+?��v�(��^�	?b�Gn�������.��WGF��=�NN���,�D+�s��M�]�_���X�=2���m��k��7���cl�������g�5�:k|*8��$��h�8{�v�����B�c�x������{I�����$�`{�[�����=�"�p��c�w���A�"y:�K������Q*�L��W���������w����P�@�<���>��,�?f��������&�_���86�E$J�`��.p"(��&���9!JQ	��Z��L=9����A��L���+�P�_�L����7>�o3��s����tuS�0�/S�j�R#F��>����H��������8�<w:�<�I��	��<�VH�M
j��
a�,��2��<�����`rO:�c�k�N� �qzE&r�skB1Wp
������?��i�,6��3m�	B�#/O�`�����E�����J����2X=[���.-Y�����!)/�����g�Y/x�C >��x������2P3B�!P��G�/ 0���+��=��2d8��~i��>��n��#�T���%��\7�p
�g#�C�4H+'�36F���b��+P���l���m��Rv��;�WpV����CEmJ���<����Ba�o�+���w�jbs
�q���������}_��+�k�N�%R�����^Y�}u}�a�*��$�M��KKJq�,�;8L��0<�Ty���p$.��p���X
7����[���d�(��������:(S/+��;���.��
O�"I�a	\w+���rE�#�6����|���K�k����*�#F�Qo����^C��-ig�2!_�����n|k��4f�ui��{L����ec���G�o�+�xh=������k�����\�=��^�GP��H��t��(�W����Nb����c����X)�9�H�$���B������12�2�`A,IOf�
�@:����YX��! �>"�S���':��<<�&E������h��FU �����[��t���FS���1HM�S6���/Dv8PRc�38���$��H�<1s�_���	%���^�3��N���N��<d��1���-��a09�$dQ�n,i�aC�^��l������;�f���P�n%�H�.�F��5���f�h�/��d����Z���,K/�� +��Sy�����"��� ������L[o$T[h�	�=�_�����Lq�z�1�a�l�=y=z�Op[��T�nP�����^E�j�^��V�KLt������z�#!��)Y��k0�F������
�
�n�4`A��&��D`����cg<JYV���|��uGZ�\��x�
e���?;j�&�Tk�#+�v�qUQ�Y�K��@��S�Z���=��u����7j��j
,���M6W�'��:��yz�y!�_(HM*,�B�-������mjM+9�5r�%`��6��R��x`A
e_V�V���'�:EkM�db���������=�[��v��$j�sR�����I�c���2�{MG�)<\[P���q�
�(��$������u=���C=�
#K���-��Q��l(dYP��>�d�F�RY����bh4�����]�A��P�1��#�n���B"dp�	��0��K��%�E�Y�~~�`�%���CrC����l��n���J>f{�g4�nV:�`��w94������As�"��)%FVWty��fN���$�_�3%
,& ����������a���>y"���O	B�|3��~=�&-��'�(4]FX\���%��{���R��{qrlQ(��13�~BX�w$I~��*��������ry��|��� �nY�Iq\*7:4d�����D�TTdT���BK��'0^�@^O�::<>��5�q���������\0�������.���4o�����+X"
�CKD�tJ��f�� K�����;�(�Q����D�!�E���
��E�j������z��R��BF$�32�A]��b'�$������%�D3V"/����}����x����(�*c�����������Z�#��	2���:�_}"�
�h�����rv-i��P;"���l�JG�V1���E�f���}�h�!�eC@a��Ga�U��/n�*��
�2�
4�r#R����"&l��FM��'���3�;e!�-���?�C;\0������j��|��+�X)E�[W�-�j�2kL����>���3P:��`��7�>�q��wf
G����'V����Bv����Z��������88n��4
W�����������:8��L;��n�qUi�����F6��VIP&���!g��fp6�T�0.F��g��Ry�6��*�l~��g��a�EDjX?�aY��O'�/_������h�~���=�.��"�$������_�����l�;&�O����U:�G���kMJ����)(y��SRV�:a�2�E0�q�����\��h���f��80���4��9�)gI�BN.Fv`=��l��v��\��}��I?/���4�d��n#*\8�4�awC��6��{g��o�y�D�:q�6�X��{�e��1^[����HM�n��������E�y�5�\�Q��M^ g���7SH�l�X2���:��9s2\���E��,�fy���������yV����AW^��u�q��HOau�h�&z�z
p
9�[y���m�qz4�>��FN<�7��4�=�l��_rA����Y{�FTk��z��'m�����R�E�*�����1�����?����/�|e�[��10�'�N�09a�q�7wO�b���sy+������}��|���y�=��&��6���b���f�[��;��|����o�0��7�k��p��
�:y����	t�Z6+\)���!��B�\���E|n��KF	V��omm�k�����^��n��5Ym���R���SC���S�U2�1)(������~:J�]�g��5�,���B��0j;�U��
���7]Rc�[V#�����9�'���������M4K&��u:�S"N�G@�`�J�����F�U1�nQOW���A���������XY���B�U�`���b��xt}U�?x�����Si/�1�N\%co�da}����W�B�����IB��9{K�)�2"P��e���A�R?Kj����%�ns���K��=�!��m�� ��
*?�����'�C<�jn������f�@<Gn���[��jBi1X'���^A�bQ��d�����vt< �F���m����������N+A�i��ion5��[�����"��<riR�o�����w8�������)�s"�h��\�lp7^��_'-�?<���f�7�9�������������v6�;�h��i��)(�.��%�U���L��r�� U�
�K�L�b��?P�/�p3l�w��a,!\�����p��X��Zt|$N��������SQ����R�0M8��n��
3'�B2Y�7�P��aL�g��O������A<2�{|�:�*Ea�Lz�,\����^��I��w:���Vg.9M�!�S���MD>k!b�4��e��~���fG����m�S�
pe�u�_��]03�v��y}�D>-�nR�����_��?��B?���<S	��S������������'�S�M�W�$��.�����.>&�H��f�`��)�f#%���bG�;�
��C;Pi|pX=������7�J&��ZM~�D3
k��z@���0b�X��UKA;����=�,�h*8��c2R�0�t�
��
�h���nqs�,q�G��:%�=+r��D��D�<K�����k�P�^4��P5�����V���<�P gH����%���&�}�m�E
)�O��&��Cn�G�Z�No._�j�8�A�9z�)u�����v�:���cJS����d�����V�^���aN�q��u6
�l��P�/�j���R$7��P��}�G�g/����~��������?��G>�Q��NA3\Y�@���@5o��4�����5=vRI���N$U2Ll�D�)���p��?�o����T����5����YP#4�"
�d�60���Z-M5���2�*�(��@S���l��E(�t*�U��*����u�����4Jv���2���7ut��_�\��W$>q�ta�9�'d��^�O��t�
u� �;���G�C� ?��C%Nl��6������\I@I!�,)�}q�z���H�y���B��'�/�\�^��w�G;�53��l�}��S:<��T�b�fq���e&�n�UH�dk�R��v�]������RYt���C����V�p�J2��aZ��	}���V0"�s�hi�9>l	p��;��[i�����F��F�1P_b^���k!�S����Yrb\��;
^��������W(�4AP�����f���9����urh�4����hZm����6��`]V]�c�a�#B/�;���!$���{���P:�r����3=Ff�u	��g���9������Hm9Dn ����~.�V
���[B�������x:��)Hly�����R��-U0�����z���0`Q�?'p�lZ6�w-y$N�@c���p4L\R�����m����4)����%�X����WU��D)�
���?t�a
[[r�F�bl��[�:� |�_�'kV{V��Zcio����66S��t���
�V�,s��sI�<���S�q�S
��$�o�)���#���������k+ �+��6K�&�VB���������!.�*��p ������m��f8vw���M��\��xH�\��j����<���DBs�c'��</����Slm��m����P�wl��LA7��`�����uC�����.F�O�rv�Pb��X
|i�'��p�F�<2[O��P�L�Q�32G���,n�dz�J����v��x����m���~����K`|��T��<���[�{����O�����U��V������T��rXs��T��������yj�/.�������������KgN��jPQU��\�!���Q8���d��=8xY��NNN~<x�Z��G�,.�6-��)�,�l�s���!n�������	�:�cU��	�8������WGO3��Y�������e"Z
�I��c.�;,�S��QL��,O��=N_�FmX�Fm�8n�����K��r����5�C�+�j������+���5g���J��������g����A���z���5�}y�P�\���'\<�_��.l���/���5��D/��)�G���'�V�#�~�R)��������F��l�������P���(��H�{�p����F�3: }��b�����JZ�-���Rs�W}/��$-:�byF��������)��&R�����A=LEB�=�� Ju)�X���N�����'6���=t�'/��%�-^���@O*T�����:|�����6%��d���B�af���A*Eo:U����+�0E�?Z�TD��eT~�`N^h�*+��x*d�h�S^$C;D-��������!�Q�Ji�������B��!Q1�����\�G������"D����|��Vxg�+�TNv�E��)i����NHr6g(C�
�R��!�*��������$�g���X@S���`��p�C�T�W�]j��Z�
0�[�cpz���=K�V*W�m�$�����k��5�r�?;8�?|!;z���
:��$LDY�K�*~������j'�/�s�c�8 �nC������x��D�~���N"�'r��B�+��'��������_~��Z����
X�T�7Dpg�WZ�wJeI�^��c1�-�����#uW6c|HC����\�y���+�F]	G����yd��Q���[�4�D����7��TD$���iT�.o���
\�eo*�1`P�^WVn�gF���TU,rR��st��%J����H�I�o�j7"�o8��U���t�R�o�r��q�����Q��G$�*^\b$L4kJ�z#�������$Nh�,3�"2��h�zM�\�����5����b��>�P�X64�w�����p�Wa�rPe:@�Tq����F����dR%E���UQ���R���WT�&�!�Z��C6��zC����[�*��$������A��
T���H������W�vx��q�A�p~4E-	��84��f�0E.�@���_�
�b������1���u?]�I?��ILn���	����	6P���ng�)�i�N/�r�R�����D������nI�/_���K�`j'(<���?k��XW�3��[`$s�T�q�uKI��b(| ����uD@S�f�]&��������l�
�r�`���>
�W�O��������Q��#��G�j�>�{�|�0���oMfGe�����$��[5���7�-���=���D�b��K�{�d�K�oMg�o��SH�~7?��g����/��z.A�v�,�[,+�{P/�����O�����[�[���t?�zf�zF~Ex��y������l�����1`�������a��1/��zvu�q��^/($;���������������#n��E��CT��~���+������o.�n`H������k�7��wK�7����KJ�nZp>��;��66�����.�o��TV�w����l����wt~Y=�O���������y���v������2/n+����~X�w�^�
����J�[��T��u1���t�%/�b�_X�5�-���%��=>�+xe]^}zr��?�$�ZA�m?y'�O=QM(*X<�eHZR��jbU����]�[�J�7�V ���R!S�K�(�v�r�����W5�b�5���^��T�$k�J~EY��0����e�J�D�R�����z�?��^��o���%����4^-��[^��\To�.����.�f��x����W/���z��J"/�K�M�`G�a��b��������e��DS;���A��O~O��-�;%�M��vR����)�uL�e�������Hi������+����P h�a&��#E4��]��~��q�	����>��dl9� B�?.�������&����c�I�������p��	�DN���q�9�����]�������6O}5�������Z��������dvc��Nk�>��5S��^6����1V�?�RZ�W������������:�o>�z0�z���Z��zd���U�U�g!�$�'z�+G�B��W�+�S�#|�%/�E�[�t9�J�b�!��,;9�u���������������T<������E��U���<!^��g�[�sk�W�w�'�X���������?��O�c�;~HB�BL�%�I"�4�A 6$�� ��"�P:
"2�@HB!@x��_��ez�;
�7��k!o������T��z�f�v���g^�Sn�Y�����"�����y��u����f^^S��f�R/�)������l��X�
D$���9����,�"&�M�C���]�����H}�QN�������TU��������*�U���S�(>����
����>��a�V�,�����=<^���C���L�������t�����x3�n��@�\�;K�[����C���a���@��������${H��_�$�"`g>e���@)�;�#(cB{��L.;�����d2A�8�\�6���8L����i������s�s8��H;����_�3$Y�`��h��*��b��d�y�f�^��a<zyn:�Z�E;A��b
���������d��8�W]8ek����t^Mt1<�U�$q`:�e�%�AKYz�K���?�/�o�8���?��y���8dC��l�7Q�?C���g�L�p]'��[x�y�Z#����g��A��fP���\��^j>�\���������	��,'��i�w?�
�;�r#;�g���%a?�8&��|[.V��!	!x{�=��a�yv��������3R�p�N8�	�O~���W{8�J���|:Z��_o.�)uy�
��h@�k��;�����U��Y�@�Ok�+f�ii�|-8�����
I';T�
s���R����4��e�B�"SD����}s���T>uE�jW�25��Y�������:����2�v��oU�_,���8���O.�����B��J�����H��3���6)�n����w���C������-�{������D��7��!\j��b9�ZN�C\5�u�s�+�2k����nJ{Y�X]� �E^Q�����d��h�.\��yx'm�o������5�������q2��4�*�fD{�+^v���W����OU	�#���5]�[���
d�����_t�W`�-�����a�V:-H��
HAA��j��8*>�k�[ �n*"��o~D�/�LP�D>�������^�X���&�\����NN'p�+��&�����C%��7������f�|�.��|(�IO��/��#�~P�2-Up�	�=�����P��������_��\s�[NQ��o��
�j��S�*P��{gU4t���2��o�uN�����W�	��A!0����r�����	��*c�*��81I����f��py���mP����I&����X�����W��V�0��\�m6F�&sb�\����@����b�Q`^�;����6�q�����d���-t��^z2��P=������5������b ��O-H�)� ��6���L�`����N�}����]F��2�Z�QYS+tW��)���k	a����@>����w�!u�r�(��U�R��B�0�f�aW��S�����n��]BF����CRO��p�O	���ejAJ=Hi�X�k�)u�t7�>�0��b{���9?��C���l�F��s�N�[�=��R3��W��b)�*R\�i>�)<� �J��%�~��_��Wi�U~�W)��%ax� awB�l���**�(����?l{�t����tp,D��s��j���Wa�}'��L�R���JD
2w��2W`��ohH�
�������5@�Y�W�Z��kU�O�4����o�j�U��
?�D�b6��%���4�<���������X��K��
�C�����/u�
�x������f�Lm�4X�[G����T�K��0����(��(����xm�>`��w��������`���!��QT�<�q� 5� ]���
��8 ��	�b��a���NP�[Q.��h�6�8���[���u�9�A�Y��������V�(Q S�U��������-�%�`�����Y����F�L��Y����.^��������Y�L����usJZ�Uqa������`�MJ'��n"��e�����2�p��q" �5�@
�)���+�$N�i��$�~2)�������xV�">x�@��~���_������������_�YgQa��(�|�������V�zZ���|~�W��C��Y_+��S|�D��@=��~�
�-�?&���}������8-V>%	[����S���?�N,�������/o���o��o2Wg,�������q����7S��q*4�����)�i�lY�!��~��s�|,�)YG?=�|3%]�+6�Xz�N��Wl<��fJ�3��z������v�z5R�������LIW����Li?��LIw����Oo����#�V���*�=�;���|�N*6z�Pq;q��C��sDrzp�8H��a�b�{����I��pxn���m��x����eP2=x?M���X��a`��<U�/�����>�������p��z��C��Q���GB\�2e+y��Hhr��m	�Z�hnVw v��<�������P������/N�+)��'�������R�>(���n��Zq��������K��H��z��-*�{*9����x��U&D��B�G&���yb:�r���QP�<� ����o/�����E��KN��d�}��G��4x�Ex�[���e��;��^��%y/��N�~�[_�i4���r����5��3W{���s�v�nM,�
��^�$[cZjQE\�q������l�
�l�&�����f�H��o�$��G[y"����o���TiJ��u��K\����SY��
r.�����j'�Jm9>�=O:��S{�(@o��^"7"+�T��f�S�<�Mcou��h���R�����2P:B��'��z����U�5�J8����l���EM2n����#������:N� ����O.G��������2"�Y�"��f�+�V�b��E(v/��>���:�F������2$��E(�";=	����P��Z�b/B����P���s~���x���P��Zz���!�;s�,g9�rTPD+�s^��h��h�����<��E��"^��{A���"Hy��R�./��A��H�r��)���������"6y�W�}��ED�?YD���{���S�!/��q���8�9����Z�L��G��5��O������c�+E��)<O�_U��<�,Q�;_M���#��q�g�nv�����?H��N;��;��g>kB�����z�����*~x�����
 ^,��+�x��������c���"^,�_.�x��E��8����Z��J �NI�V�#��-UJ�K�O[�/�rv�X�J�_��X4q��_5���"�dO������+�VD|�A���'��������E�"\����(���-���8^x�b��Z$�VA��G�����C����X��*b������6�h��3��F�������]D�."[?���E�������i����i�����������h)���;�b����uzV==���7��UO��B|��G�*bQ����Z��,/<�?���zz���|JVF�fz����"6��j�ge4����F$��"C�Y������L�����V9e����de�j�gy�c��j�ge4�E�-�����D���Y^��S�J�j�gy��c��d5��2����;������'�m�B�����f�VKO>����'���������|�(o�\��1��j���A2��Q�,�X���8�� ��q�@,5������,��o&3"�O~`PqS\~�"���q��F�����X_����a{F��hK)q��ea�56����cs���<g��xDq7��B��mP�E���al�A��UE�PZ�������vFM������]D{|�����P�A�����A[o���}���kz�������p�Ed�Y���������l�<�R��+���B�� N�������r��O�9�Qg�Cq����3�+�����f�+�l��L�
�@�����<�����3������v���������G�����Z����w�\��������=�������gs
!�����+�;��k���i�c>\����j��;+-`�H��4�����B^��3g�h��1c����p0.�R���/<.�C�L�zi��|�z�AO�w�?�s����+�73�����\n�:-0��8��k�z,��b���0�d�q�U7����U�X����x*�aQ���&�X��yL����b�uh1�v��X���;��.
3���?������m���_��`�����oik�����J�9k�q�$�
����]�L�I�w�k.��y[��"��9�Um'�Ym'bW����&���N;���vr��v�1������m������z�em�V�����V�f;�&��M��J���wi�i�0��#Y����;;sZw�Wo��]�����?�]g�v���;���i��>nn�yc��\Y�����V����[��f�vg�����Zpv>�	�����sv�U#���f���+�qv���sV������Xrf��On��)��ol�Y������`�Yq���8l�Yt��<��������t��<6�����V���Qg���/n����:11n��);}�f=��,`��s��5�p���7�I���_�\���W`�Y,��3�,`�Xc���L09�0�����s��|a�Y�`��?��g��9"���0�TES��M0����Uwn6��++�%b���R�����\���j�Z���e��������#@k�B�Thn��,��^�?o7��yv�{����e��������������
#23Pavel Stehule
pavel.stehule@gmail.com
In reply to: Nikita Glukhov (#22)
1 attachment(s)
Re: SQL/JSON: JSON_TABLE

Hi

so 28. 9. 2019 v 3:53 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

Attached 39th version of the patches rebased onto current master.

Regress tests fails on my comp - intel 64bit Linux, gcc 9.2.1

Comments:

* +<->/* Only XMLTABLE and JSON_TABLE are supported currently */

this comment has not sense more. Can be removed. Probably long time there
will not be new format like XML or JSON

* there are new 600 lines to parse_clause.c, maybe this code can be placed
in new file parse_jsontable.c ? parse_clause.c is pretty long already
(json_table has very complex syntax)

*
+<->if (list_length(ci->passing.values) > 0)
+<->{
+<-><-->ListCell   *exprlc;
+<-><-->ListCell   *namelc;
+

It's uncommon usage of list_length function. More common is just "if
(ci->passing.values) {}". Is there any reason for list_length?

* I tested some examples that I found on net. It works very well. Minor
issues are white chars for json type. Probably json_table should to trim
returned values, because after cutting from document, original white chars
lost sense. It is not a problem jsonb type, that reduce white chars on
input.

I did only simple tests and I didn't find any other issues than white chars
problems for json type. I'll continue in some deeper tests. Please, prepare
documentation. Without documentation there is not clean what features are
supported. I have to do blind testing.

Regards

Pavel

Show quoted text

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

regression.diffsapplication/octet-stream; name=regression.diffsDownload
diff -U3 /home/pavel/src/postgresql.master/src/test/regress/expected/json_sqljson.out /home/pavel/src/postgresql.master/src/test/regress/results/json_sqljson.out
--- /home/pavel/src/postgresql.master/src/test/regress/expected/json_sqljson.out	2019-09-30 11:03:22.942999302 +0200
+++ /home/pavel/src/postgresql.master/src/test/regress/results/json_sqljson.out	2019-09-30 11:10:05.994831367 +0200
@@ -1032,8 +1032,6 @@
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint3"
 DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
 INSERT INTO test_json_constraints VALUES ('{"a": 7}', 1);
-ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint5"
-DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
 INSERT INTO test_json_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_json_constraints" violates check constraint "test_json_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
diff -U3 /home/pavel/src/postgresql.master/src/test/regress/expected/jsonb_sqljson.out /home/pavel/src/postgresql.master/src/test/regress/results/jsonb_sqljson.out
--- /home/pavel/src/postgresql.master/src/test/regress/expected/jsonb_sqljson.out	2019-09-30 11:03:22.943999304 +0200
+++ /home/pavel/src/postgresql.master/src/test/regress/results/jsonb_sqljson.out	2019-09-30 11:10:20.051860385 +0200
@@ -909,8 +909,6 @@
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
 DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
 INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
-ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
-DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
 INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
 ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
 DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
#24Pavel Stehule
pavel.stehule@gmail.com
In reply to: Pavel Stehule (#23)
Re: SQL/JSON: JSON_TABLE

Hi

po 30. 9. 2019 v 18:09 odesílatel Pavel Stehule <pavel.stehule@gmail.com>
napsal:

Hi

so 28. 9. 2019 v 3:53 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

Attached 39th version of the patches rebased onto current master.

This patch is still pretty big - it is about 6000 lines (without any
documentation). I checked the standard - and this patch try to implement

JSON_TABLE as part of T821
Plan clause T824
Plan default clause T838.

Unfortunately for last two features there are few documentation other than
standard, and probably other databases doesn't implement these features (I
didn't find it in Oracle, MySQL, MSSQL and DB2) . Can be this patch divided
by these features? I hope so separate review and commit can increase a
chance to merge this code (or the most significant part) in this release.

It is pretty hard to do any deeper review without documentation and without
other information sources.

What do you think?

Regards

Pavel

Show quoted text

Regress tests fails on my comp - intel 64bit Linux, gcc 9.2.1

Comments:

* +<->/* Only XMLTABLE and JSON_TABLE are supported currently */

this comment has not sense more. Can be removed. Probably long time there
will not be new format like XML or JSON

* there are new 600 lines to parse_clause.c, maybe this code can be placed
in new file parse_jsontable.c ? parse_clause.c is pretty long already
(json_table has very complex syntax)

*
+<->if (list_length(ci->passing.values) > 0)
+<->{
+<-><-->ListCell   *exprlc;
+<-><-->ListCell   *namelc;
+

It's uncommon usage of list_length function. More common is just "if
(ci->passing.values) {}". Is there any reason for list_length?

* I tested some examples that I found on net. It works very well. Minor
issues are white chars for json type. Probably json_table should to trim
returned values, because after cutting from document, original white chars
lost sense. It is not a problem jsonb type, that reduce white chars on
input.

I did only simple tests and I didn't find any other issues than white
chars problems for json type. I'll continue in some deeper tests. Please,
prepare documentation. Without documentation there is not clean what
features are supported. I have to do blind testing.

Regards

Pavel

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#25Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Pavel Stehule (#24)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 40th version of the patches.

On 19.10.2019 18:31, Pavel Stehule wrote:

This patch is still pretty big - it is about 6000 lines (without any
documentation). I checked the standard - and this patch try to implement

JSON_TABLE as part of T821
Plan clause T824
Plan default clause T838.

Unfortunately for last two features there are few documentation other
than standard, and probably other databases doesn't implement these
features (I didn't find it in Oracle, MySQL, MSSQL and DB2) . Can be
this patch divided by these features? I hope so separate review and
commit can increase a chance to merge this code (or the most
significant part) in this release.

It is pretty hard to do any deeper review without documentation and
without other information sources.

What do you think?

I think it is a good idea. So I have split JSON_TABLE patch into three
patches, each SQL feature. This really helped to reduce the size of the
main patch by about 40%.

On 30.09.2019 19:09, Pavel Stehule wrote:

Regress tests fails on my comp - intel 64bit Linux, gcc 9.2.1

Unfortunately, this is still not reproducible on my computer with 64bit
Linux and gcc 9.2.1.

Comments:

* +<->/* Only XMLTABLE and JSON_TABLE are supported currently */

this comment has not sense more. Can be removed. Probably long time
there will not be new format like XML or JSON

Fixed.

* there are new 600 lines to parse_clause.c, maybe this code can be
placed in new file parse_jsontable.c ? parse_clause.c is pretty long
already (json_table has very complex syntax)

Ok, the code was moved to parse_jsontable.c.

*
+<->if (list_length(ci->passing.values) > 0)
+<->{
+<-><-->ListCell   *exprlc;
+<-><-->ListCell   *namelc;
+

It's uncommon usage of list_length function. More common is just "if
(ci->passing.values) {}". Is there any reason for list_length?

Fixed.

* I tested some examples that I found on net. It works very well.
Minor issues are white chars for json type. Probably json_table should
to trim returned values, because after cutting from document, original
white chars lost sense. It is not a problem jsonb type, that reduce
white chars on input.

I did only simple tests and I didn't find any other issues than white
chars problems for json type. I'll continue in some deeper tests.
Please, prepare documentation. Without documentation there is not
clean what features are supported. I have to do blind testing.

I have added some documentation to the patches which has simply been
copied from [1]/messages/by-id/732208d3-56c3-25a4-8f08-3be1d54ad51b@postgrespro.ru, but It still needs some work.

[1]: /messages/by-id/732208d3-56c3-25a4-8f08-3be1d54ad51b@postgrespro.ru
/messages/by-id/732208d3-56c3-25a4-8f08-3be1d54ad51b@postgrespro.ru

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQL-JSON-functions-v40.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v40.patch.gzDownload
�g��]0001-SQL-JSON-functions-v40.patch�<kS����_1����[I���!��H*�J�F�#�f���Lb����3�������uM�������~O�����A��;bw��&�A��j�;�^��7��{��#�X�{�:�J�Y��Z�}���Z��	��gg��p���n�{v�4�v�~��~0��?���+/y ��u(j��ag���j��Vg�����j��jU���{a�������������]�}������MB�,��+�z�^a���5n��#?��3�~�P�`c;}VM@**G��i�9�|s?��H��t������3��5�S$m��-V��T�s�N8f����i������%�����F��-�"*>#\�>�{'����'X{����0�n��
�~oM����/x����<b{�qM�7
w��L������~�������������N�[t����}�`��b�}��3�+��
��]��v����B�����;������s�������x��,�1hXv��y������I���kN=>k<�SB���Z��������6�p��D�N���@%d��3`��1�&��T9DH@g�����#�
rG6�Mn�����iH{���9����e
�����z��E�Gu[Z����s�KC����F�^��:Bg��������[�Nad	�����S��i�i����#x�-���o�Z`
�r;4E; ��)��)����,�X����\x"Ap9$�x#�O�������m(���n���%�����z�<\6N�!�w!��l�����
J�).�b�z��|gd��)�U.�������dR�V�`����|n-���s�����\������BSd�&@!I�@�
9�1%�*�<zc�M�R���[���y
����Ta���v�
���eCL&�,�i���W����A2�QE�c'��"�,�7H�g�;4��N7�@�a��7��c�Ih����s\�H�i-!��m[���o�	.8����s�5/��)i�?�����}��mVJs����,`��%�����E���h���o��l��q#n�������,p��VZ������n��6�!-���c3x�SL�z�B	�]��f�>3n�3&�t���JB����v
9��La9T���($��`3p�0��A~���y
|�X�>��kC����	��9~h�bZ�	���V�xs���x]�
*����w�A��f����b�d}**`O���X���������]�?���-0���O}_>^!${��0����9&?`���3��30��x�c��-9��o3\�]�����n����u�!�������*��i����	<A�&fKR��"��@��f��������L��I�@^��Y�i�Ouu��;��>��1��
��z��s���L�`���ao�6@u�����'�C��,G��dt�Dv]XW��r9�i9����ox�D?���^�[�������lv(9I�]4�����Ujw8)�Y��+�0�b9��L����)��j�Qt�Z�5��?�����:�����5�ETV#*����C!�D>������E������B�]&@�l���+�c�&��Z��~���� ����{����G3�������'��s���"�K�f�/_H��`d%�B��#,���}��#�f����3�����i �B�f����M.��$|t'���Q	G	�/��P��CK�v�ZG[��z�������������=�fWqD������<������9p����H�y���`)~�~�5��}r6����[����8�9+=�_%�lqm�d��S������7��xg2i����(2ii�"����r5�CY"���kz�882>+p�!@^���t��[�$��m~�`���a�ln[��p�g��B8�}��o�|��&�c�BL�4����Y���$C��{vt~|yt<:}s�����zttxu�
�]g=��5b���������
=5P�!�mi��-��[�V�S��1�1�7��S���G�t[R�����!��h�CH�c��3��W�R�$4"+IT�����x�_��x%���\.��2����c^�Z;�S�����8��������5�_<{����%�H���h���3����I�wI�{\2���3�n��h���7��=��J;.�D�iw��=L���Nu&��;�0��9(�4}��u��X�Gzb����|Z
��������A`�GM9���2�>����� ����\�}}�L��[�3�?o����~�A���@�����3�]�
p����)�[�<�p��&?:�A���.r���q���6�=�O��3�-��%<6������5>���0�h���&6��
}�z@0�v	����{�,�4�ll&fc����}Xk���d)(��d?��l��NA*��)����n7������������rM�$�.��(Q�o�����*u,V*]��{b����7�C*c	��+�q�"R6��|w�+�|ww����ZEz.�s�@3*�?w�����CtF���UiJ�"-z��D/�fR�@d� ���uDy�����q�1�~��#j����?'�}Er�x���6Wg��t�2���������s��:���<�����Z�6KP�{�s�5�g%[�/�]��(�ySiW,��x�l��L�� .��=>����0�N��o�c���39�[�6�l�P)�V�x.�>� "�
rm���[�>`�$�)��B`�t9!x#�����G)�^�"��l$%�h?i�>{tCt��m��$��:S�����S�Q�r��K�s?�3���S�h�RK��a�������r3A��u�axV,��1&�x`?@_	1�r4�$��k�3�\*����2��������r"W��*��T.���p�=���D@�)�P��9����m(���M!^ab��A�i��&�'j<6w�!���]/#
�<-����C�.x-�M0	'i�_B�A�\6�:����a���^x��4q8�����*@��B�����LSr!6�$�E"	�"�rV���J��M38��@��m����f|�-8��P�E8P^��"M�DH4���������^1��:U���q!k%7dT�����#Lv� �9�#����wV��=f��G	9�����!-2D#��y�]�W�S����������l�9X�^rEy�%�#������s����l�hJGR�����I�7���3l�������k�����|���"�V��4:X�oZ��UE

Q�F�/~:>�>h����y�A
 �����zKz��<�W�?�Z��o�r�@?��l�R}��B���
��3l��p;������N<�b�[F�������c��m�o�O���c)�w�������<�;v|vt������>����O�j��h�Gy��������W�g��0R���^�����
�����������b
���������|tJt�_��Jue9t,�H�i�%$	�oG*"=�K��K���S���V���E�q�L;^�����|?������4R��2�FK���t�%H��P��]��-��E��{�"e�0��d�Q�A�W��-�r��� ���_�5'\�T^CFF��7�e�B5&l2��F��q��(���_�%+
�$cE�F�+�t��,TruW�1SL,l
%�0�v%��}tRXu��~���,&U|:@2�"���4����]��Q�H^������X��%J5����1�M!v)\��q@9(�H:0�):2$�X������J�I�#���K%G5&������J@���l�P�zB��.������S�z�l)3�_fv+8D�)�	P�)~sC6��	����
z����'��8
����a�
 &x����B$��H`-����{��5�i�Icp��<�nD>��y +��;���"�8�<hf�����4Y�1�9��n��+5uu3B���}�ZZ���~h%�]�4���Y^�):r	�)�h�+*1�����X�;�G��gu%1�2��,f��|PPi�-J�Q��JT��:�fE���V�vE)�l1���a<M��2�,����|�Mb={�r��b��?|}#���2�\�V�N�e�����2T`�v+����?n����k�/���4��oi���
���S~�U5J��]4g��/�G��Vw�os���?��d �,H����'��W5�4�s�L���c���}�tB��Z��`b��w��H�<�R�j�����O��U���������A�~([��J��j���Q`X9`����6h�/D���k����$c�9,�!����S����=�����t��6?�w�e�3�|q�y13|LX��#Q�PM�+�}�bZ�9�x����&�N-���������\�%�:U,��N�q���l�\�N��X��P�sZ5����8Q��L��+*������"����>]��Ri�|�U����|�f~6io��M�%������k�X��h���JF�N���m�X��K'�AXZ�tG�%�a����=.%IJva�����7������>��<��Pk{��4�m���7�����F����I@qkW���(�>��g6;�v����w[Gk&�Z=�����$m��mZ���w����������J��\!��pc�P�$���h�c�/�F���G�	�6�d������RU78u�f�Wt����2��������?��_�0����`9uhH�@
uqU��]|���Gz8��^�'��|����7����Igc�#�=�!�#�pN|�T��(�m*hkk����6�i���&�=�I��J
z��^��xG8��AJ/w" ���x�[�����N�.,��AmE���D����[�m*+�,(�\�R��-�V�5���I����U���H@K<�*i�\��R=�<�
�J���/�jI|�*&p<U�~R��Q��F!�i������A�����������^@&)�e@�4������9��.�����\����x��w�����w��^���������B��)
R�����������f�������:w�t��H���>i����%i9Uu1h�\n��&Tu��-G$_[�z!�J��������G�����)�j���c��,RD�Z���<��`/~;h���y )Zx~���2�P�Nj����n��
'�Qc�,�j��/��o�'��0s��G���zW�P��'�A_0m�z��Z��Z�_L~�d��!L��Z�_,���U(�R�	�
���r6��|�=��B~&�Y�B�3�~��
BA=C��8lD�1�f�K�G�%-k�����X���`�x1~�|����~'"��k/�1����W�}�:�TBJn���h����ZY��������?������������O��~k�~Nu����?�����������J��Wk������J��'���eK�&J�k�g#�/����-W���6y�E��Z�T�������P�����I��r�d[�(J����2�U�CQ��>�_���9|�
[@��t�7��
�J\��������������8$-�6q^����Mb����7��{�Rv���`_6�r�%����04O������d�N$J���o�x�/��LLW����D.������brQF��he��q\ @��)�Vb-�j,��d}UR�^��m�L����o��/b]fE��t�)�;���Xoc�a{�Q����]�Z!92��a�z�W�o "\������W��
�:��#�P�����������g��r���]5������%�_x�;�8i��re{��+�/]�E{#���gaP{�5��F�v"f�GP�������Z��[����\��zM��	8r!���x��/���8�'6��������l���@i"�=����%��� ����
�O����yW[G�0��?�	�n[2#1��se�:h$g��YZ [H�$���������Sg�t�s�W��sj��k��=nj�zk������ x�o�v������uw�a�.�����Ms{jX�w�a)*E�U��`��T����At8�c��Us�c�qgo:@��zlm��K[_E����E��dC����Z0-6�^P����o��h?�?I�����a�3�Z������Js����\�<�����$YS�;���Wu�M���w��y��������e6�N����G�!?k~�_O����~��K
'
�������}U�����%!�tzA��"r��o���`�m��&�EL�D�a�)�#1��F�*����?3�����	�*7��;h��P=�K	R�
N<����k��+�J����>V�xT�h�z"�B�c�7Hh(�����@D9�0v�$	���7"�q���C�&�j@�����<����
��O��:��]�98l�����}�J%���
D���M�f���%/���g��=����]uw��-���;���������8������E���	�]����D�>,�J|X~K�a��(��h��������h@�D.���T�X�t�|Z#l��hG�UF]������U���`-�YGY���.l	Z�~/&^]��� ��Pd��_O�����'.!��r��kkLWNS����(sQ����R��#��sr����f���fZ&b�y�|I���r�Vr?��-F�OJ^X��������/#���+w3*�Z�["�Y����R��x�=���I2�^x���Y�� {��|�mrN��.|�Y����O�������E��2�/��,C���c�6������j�r���.��/��J���7�d�����Q�-���S|l�O���#y�*���@�K!��������i����4����E���'W�n<'�-:�^Y^c(7]}�Q�j�������w��w]#sHZU���sN7<���RL�<��J�-i��iV�
�2��*�D�5��$M�,�������<���rk��!���?�i�{�������e�T#"QL��D:�G�T#�NJ�7�K"	M�O�*��j��Mp�Z��T���+Va�U������a���+p���@E��W��1�II��'e��?B����a�����}r|8��X43�]������YJ�JB�1����f����e�hC��A����J��9�P���Qo5�V��qHd��:���$�!*����I�q���NZ��4�P7������E���
�����S4�&�u�l{�TReS��Y2qu���Y��1�e��?���OH��R	��T�p0v=z�Ab����ig��4�.��~A��Jb�Wc4�����S�j��Y}x��J�������>�����..��>���e�,�s�SG\j��N���t<�|�HoX>� %r0�L����������G�V3�����u]��D���$�Rh�����`br-����s��A��6Kb|q
�1�`�G��~����'?���t�����,����r�Z�X!�Z\$#T�����O�R�b�g^UZ�?'�L��%���>q�Z	�"���&-�}�HD�0�3�T�������	��Z��eQqW4*sUO��"T\D�Xx��KH�D��,D�.V��X"�m�H��w��-�Z��O��>J�*��^{�[�X@xVg�u��]c�T�K�1������H�J4@MQ&�it�N����\^�x�l�H$`��%2������4������~}��:~��t���`��J��/�����Ge�����_���D�����HIm�B8����f@����V�N��� ��5�Yl�������
�N�:�n��DR�aE_�K��&��M���4h9C?0,68^���W����l����<A�3����{?A6���&|/,�"J��.A��S++I#`e6f��_H�E����a/v�x0��Y�k���@+��P��������V^��]C���~��X�0���;l�Z������3�p���������|�+eL?�����t����;�V;�c�y�e���7N��O��B��
�u<]��9���\�\~�z.G��U������"�%�����KBxz3WE����b�@][{���I�ya���X�s���rIsd�2���OO�u;eC�kf�8�������������*f��������8\���F����ml�uI0�arS|�I�}����
mM����>.����DgZ��]��/�I|���hl)���}1����x��Y6q���L�]h�6*��fA60��>oB���dC&��
���f"��}:�|m�����d��r�uu���*��
u����2�3�����r$�}�����y��kh�T���X��'-�������UtV\�e����"U1|$Y�Y	#�4����d�Z�X��ZF��_�X�����37B��y"��
X��`?\*��`4O��w���u����|}3��W�V�k��U����cUZ������7G�/�o��������=:,��'J���;�4X�� b2x�r2�X���Z|O�G��p�"@����-5���o%[�i�Rs:��i���������t�'�r/N�W��H�L�S]][��Z�p��
	��tb:l���c����fi�Z�,���?�F��U�����=Y�QT��������[q���D,�,T�N5���5��$�4�+�g//�s
C�s0qxppzrx�::=�#7�����mqd������gg�s�����9}s���x{�j4�4t�<����f�G�[���%���yh��$R�9r����z��v�5S�����g�����3+�7ho�J4+}Y���9�i��`��T2���D�������^�p)!~�F1e��7�����wo��
zIt���9��un������aL0��g���$!����\)�2�*R������������OwwYh�,|.&N��h��1����������I���z-4O$�p���`"�S�y.�8��{<���-��|�_!a�t��+z>�3�ya�B���q���4
�:�P�[�#�x���1���W��^�.r���mO���E�����@<�Q����r6aR��Y1����p|0o����H\���x�yp�Z9(�����?<B]g`UG���I_�$.�*�������������<���>�'D�0��7��Ib{���F2�m�V�9���X�5���Z�V8x�������$�������U����Ob�l4��*����H� ��'#��_�������z2�d����7�&���+������<����Fn�n��2ai��6��A���q�?Aw7ZYHf*������)��@@�p*�P�]B���������O�$O"����l�W���#��'G�Z�y����Ec'��� �LR�����>���(7*�����Qd\���5R������Wy�5�{�R!*�e:_O:S������������t���S��>�d��`���f��W���r��y��G����93��b�sk%����30�JT"�v����.J�D��������pN����	��}e��"��.����c2
�J������E��?���w^b��on���=�`B���c���S_bM
MiP���i/i�6���%^�R���4"��E�]Gt�"{M\������jM]�*^;����fo0�	1�;�NR��u��M5SU�;����u�|����x��GM	t����c�����f���A�0BII�|����M�E�������g��c7�?���$C��*���K�I�9�;�b����:�E
;�z��Mfj���U!�:��[d<vH^NA������c(%<
y�x8��:�<
��**�`g8�����o���%�@�iwEe�]HB����X&�����?��3�X0�\xd
�����a�r�6�2���t�!��=�������]D-�����x�ak�%iZ�9�� ����k�f��a���\�V�I�`�u�-� 9��^�o:��LO-�S�HL��	o���KN53x�%�f"�TA)�������L����t][[Fu��a��9��*y�M��jC��8wlw���\~���y��]du����k�A�[T���Im�y������H2�@.����8��T�?����[tX��
��P�7
8��f�kcf���`wAM	���:���:������"R[2%B=������>O����a�)l�l��pQV��E�i�H@i[�w����o\&Q]�,���@��a�j�2�M`N�+"�G��
�X������+KI���_���&�*(�J�>"��#���75M�%��.���@���e	����W0/�����������s��7""x�����Js�{�.R���� ���'����'ofb����Y�FSBbJKL����Cmp!�h�tu�3�C�m��h97�S��]��nX/���?��H=�U��hC���l�Fb��%��4��`�����D)�`(Y��o:�\�\�AK"��(���M�~G�|`N�n�����it����	'2N�%gV0Q�]������������6�����A:��vzm���X�����-z����>u��p,Q�!*AcB��^���7Sq�����r���$��e�9	Y�h�EQ"|}��$���D�>#xq����$#��c���A~]���{���O��_���H�(��B��:
����YA/�����|fx
*�!��9&F�uO�j�����v
����I>N�-����J������t|@H��������Vi��|��r.���	�z��������c��w��:�~���h�8u���f�1��g"�{���� W;*�kXL�>6z$�����a���3�/F����F�l6�=��c���n���������};�?���(F�B�
F��c�wov6w��67���8���������FS��G+++E�����V����v�B��j-������o����q~R?~D��p�lr���y���q5�����|�	8�W�l���l�����>V�?=��g���F�����X�z�UP�w��1_"�>c�;~�������v}����Dbh��l0�;�Hju���p�e���&i��$��"�8z��m"+Y�6���%�\���a|C��(�������=~�w�9_w�������>c�b&4��'�l�N_Q�0g���,)�
���C���q��i���?M���O����O%�Y�~1:�����_D���_��?���5$�y3����~x����|P���w�b�������(����+�
 p����I<�p�3�7��c�8RuF���5����w�"��5j�.�(�<PW�]�o���
��H ���CI7Y��p�vP�~����)}i|�L�z�E3PB��;��.�c��6:�j���~�
�����J�mvs���w�����o0�
o�q�|3g����j9��{3��Y�e�3���7+����jC�p�:��8�v�ib^��wk8�����:��gs�qr;��L�%�_��lM;��Ag8,���sU=�����Zt./���hI�Esm��G�
���s�����B�#��:��2^���.#��{��#:
���h4��<���h����
;#)�j����������ji�D}@x����i�3�H�2�)�����L{_6�NsO�Yo�'q�m�y����gO�"�3�p��s����,EX~ez��1����3��J8���o�\�.[��{C�@o��VSd���l3(���]����>>�������_���&�XO����8�����a���e�c�Pt((�RK�ZH1�jMyO�Q�qz�~�~�h|�<}�����z�(|�	��������p	�=-�,��q���-ZC{�&jm�&��^��P�},S����zB���z5���dcD������!����6��x�X�F�����cI���IG8����������tR����gO�G���)Y���`T}��m[�H�#�����ze��T��B>��i�3�l�P~}~�����[z�?��^
l�UoKKom���-�����[z5�����~����4���V�����������V�l�Umr��o��������7\�/��_�}&�ok����N�Fg�B;%u��8Hg��m#����M���d����m��xE�o,�mt��
n���������]yDx,p��D��,���a���q��2�om�E���aQc0�V<�z��e�'L.��Pd7R�ng9��p�p(�c/J�tk�������f���
Zfz����A���kLww���wl&�F����"Fp ��f�7_*9��Vcr�7n
�%�94��x�>?sE�0��N�
F1'��^V4��U�N��XC�y@�a/�m5��
�J��7~>;�w��������0��Ur������	Z��J3�������*��n8�j��GRE��^�����d����O/�h���tU��K""�Sl���b�5���@:��]�tR�O�m��t�_.����/����Y���������c����G�u�]����nB��,e9�!dBA��K����#�q�1M#�l!K�Z����Y�x��.�(L�`�E���j�z0oK��?������F��.������r9d�N}�;�4!�P�?�r������
�����T��&q����-(A��x]0�DFC,c?}��T6��$��jc���I�tq}9m��VF8VU�K�"��HW�#��@��������!�3�w����z*�pM��3��/K�y
�k�F_��'O[|�:��=t��8t5d����(Vn�h��z���3%Q�C���E������o2�O�7�
��5x�{����t��L7J��"�J�[��GN�X]��m(E+��e�}}W���@��b�y��7����r���e�������.����TJ)H��"8L
3�=Q��D��EG�>U�����2�K	o��R�G0!��D���������B�p���S�F^#��	��,��US��@U^�/��J=��Y
��(6��fi�����}���e�,�_O���Y&Scen\4��u+�X������]H�E]$�N�|V������I6���7������x����aEW�7�9�q��n��p|Y��i�h�f4�r9B_��qv���8���Q	��|olu.�*�xZ\gJ��I��T���z��}��������nw��OuK���,^����w=]���XWj���z�l��*�L�c��z*Sy�._�e�<�lO����/���Y����yf�����>�*��8���Ju3ZQ��E����5}�^^f�N�z0���h�:�cdf�Z���
���2����eR^��k"b~u���I�V[k]x�
���qM�����d���{O%{�*`���(��"��5���I�~���z��h��M6��Rcb������ �D[�uS������P�����F��9?����F���������q�$��~Lf+�����[FI���_�n��K���l������,��^�9:9{�j|�8��]?���Jdg�p[���V+���g��p����cp�&�Fq4���p u�u(���������9�>�u��13�T"��50�6@�U��"�����p:���^p�+���KP�
(�1�n�*��5 �[��
��S/�V=���}l�	�6�q0��t�\wO��d��=��c�_��6�����Kcg�_�H��Jn�%��_�@���3:�p�&BS4����x]��T(���]&z����,��A�'&6m�iQ������u�A�����Tg�/�x""2}�2i
����}�����6EVnS(Q�<��=�;�M��u<'H����N��N��J��<:c��.�c��|�6���������Aq�����|��/��j��m8�y	+�[�;aF�W��fFm�1L������woO~89����0Cn��G�V����<:UXO��GV��
C�q�G�d����Oo@d�#�S��|��W������X��e�Q�����y�s{�yK9s����jS�"U���b��V'�5�����D&2��n{��d�8
����������0��q������,sGB�q��dx�������R�y#aU��*mD��5,�u�$�x�5����#�F@}���y�`W2e)Ase�71s��lA7�M���lqnB����!�0��Fu��1������/�����F5�����Wd�����G�&E�)=~��t'd���H'*�g��� 6!F�i<��P$��1���5n
O?����������.�����FL!�l�A��7�EC���q_�i+K�����j�t,8&�����)�M����!��@oJ�(9On�BOT�l�./��]"�f-3���G�����9���A^XW��S+��9%��Q�F!�TL��z>�~r����]@��58����I���-`Q@Y����Q��C s3���a����!$�H�K|6���FoEh��s����8�G2Y,zDc'Y��Bx����)�RP�74@ �H.�F0:�X�%��
FAj��9���q���h������U	[���`VB=V�H�#�Q4� �����u�H���H�D����%�{eE���=�UoV����!�F��40���D�-�iB���=3<��}�"
�f���q[woO��Y&�nS�^M�����Y�PE�g�z��PY����������X�^���������Y���pum����\�D$���'�\o<�$0�v 4*������������i��265�)�
����v�a�sE�������L)i����R��DK�y�g(,�U?KB�����7��������3�T�)��Y)�I���I�d��D��k�a &T
MC��2�3�v+%��A�bz����=0= �6z�g
��\��0�����?6���{
�����4F��.��*[}��Y�i1�i�f������-�n��H3��t�p����q_�H�x)
�"]N���u<�r�Be�����:O�:L�
o�����`�����l��Q��<P_�3�S{���D��\�uwXo5�-=mB}K��F��h�)�%���kd���f�����b-�D?�������s 	0�p���T�/'q��E"��"P���:IGN�Il��~�����f&�{hw[c������>��!Kh�AL� �Hb���r#�G&�����!|�Qi�F(��q/x=-/.�6,����k&����T���-�j�tI.^R���������f��<4p�1��	3�l����������X����T������Z��|	�:L�vpz�h���?4�����������Ng�>�#�Fj��$�xCwG���oL�n�h��� �;�g��i/>EU#�!�������P���H�Z������`���aUI�!�HI99����:���D��������kA�� �Gj"�y6��i�Kf�jLg����_D������A�V:Uc4�(4���=Mqk��{9��[2���C �����%�?N�Y, ��%d��$�Xh�PH)iD*��z��{
��!��G���f�s�����5�(%3)8Jj�j<���T3}5��]�Sb�K6����4�����B����
W*�DA��*K[����s4a`O���}#�da ����u5 hp#���;@��Q�����n�j��.�F���'cr�B��x�B�:�P������o���m�m[i��9�����zPP�*��m���D�G#u���%u%���O���Nu��L��:%8l��fE$Y����`��
�����BJ����<J
��0���
#���g�i:��������g�{ckn��n�#������mn���TxM�Ib��G�D�u��1���TV����W��,����bm����
�`�9h��:q��k�iB�8b��L�S����F�F��3/i\w=�hI�<50�/����>M\	�Q�m�9��TD�P|B���GZ�0Eh[;��pN(���[
���Y&g�����@���XJ[��c���oI����-��p���%f�{i-�#���(6����"0���N���t�V��	�v��J�@{~��1�
���5��m	�����a+�-Q����f�4D���fI;�dE-�g
z;�^/��G����v�^�����+�bA�����u����=`�����Q�������f,%���9%l�Es�*n�������R�h������u0&,���\:=��r�\����<�aDG�N)�����M�q��umLL���K��%) ��.�P
�(�"���������)!��Y�Uu1Qp'�!Z Y�Y#�lWT,2���V�
0�''�-��&���v�~���~9k��1"��%m��3�2�f}����O/%�f���y�o���e3[������i}:#��kA�X�,���G-��u�s<���Wl��c7��eGHPJ���*Y�������������j:��U����������!>�I��WD3�m�&�������g3'�����YOX�g��<��tD)���T��Y�������E����ay��]��'����;B����=14�1������0��!11��Ua���������a���9k1�p��=d+���x�����^�c��-Wm�tj�(�C[R#���]3�����=�9#Q����zw�!#����T�m�5�5���K	h�<���������7��8��<����>e��������+���E�6���O���
UU0��N������|�:^&��j�QC�z�h����a�C4�����1��nr�-"eYHH"2
%	HY�[I�$v��x�"t3���H����Z��<���O�F6)���A���%��SGKl�1�-�\HV����H���S\O�@��f4�1�Dt�'"���\��H	�����\��W��^� z�&��L)��GF�e��O�$m������*[��E�����3�^����2Od0�l��;�X��&��|�}�u����3�l��N��1��%{�[�5�"�H3|������5[�E�*�����U���T"�����O6�i���l~&�3<&SS��[�c��k-}R[���\�*o�����P2��da=;o���$��g���M
c;0���L�Z'�g������;�n9O��ze<1������_����
�����k�?����iO)%���������Z�������{�����gO+I�67��?��K�{_��&��2{����"�������1=������8[��tr$tp|>�S@��~��g4����v�^�ek�n��d�m@_��G�b��" Xc;�7[	A�%��f�)�w�7�|b�v�e�767j����Z����lo��~����'��k���8}b���E������D9�"�=E-.����/JX���q|X�\^��1@�o��-�Lo&�%f���U������'(���'���������n)�M��e
��.#���7eX��3,�j,~���?2<��,�|�j)�������0�`|�2����[L
�s���4�
�3�n��p8H�rJ�K��|U�6���y_x�j��6�V�V+�=
�S���zs.�C�e
��L��9�k:�������8��
��W�{�F�M�TFbv�?��U_�K������|W=��O�ar���3[����)����H��*�2���� b���b�d����8����3Q����]����*e��H����Sf\����1����,t3��P������S9����z��T=�j�y�4/R��
��t&l4��+��w����7F{�Tx%j����XL��R���k��
n`9�v	�
lx��#T2�E�M�������w���{8����<�f�c��"�[����T"�����0����\K��{g����hR�_1zLVgi+�#�q�V���M�|��\�r&��Z��JzS���LY��s��Cjrp_�7I������+kO�����bKCvk8��'�I����Z2�u���b)�G���#����vB��O0�?d�EQ�
?��w�(�h�Z&q�ru���n������A�S��Q�3�p<��?�J��*�:�!e'l(�;L<l�|H,���i�01T������6���o%���o]�g���4���������\z��8�%
+����L\X����7����)PtJ������vv����;���;kbsr������"����)��Kg�2'7���%�������djn9oM��t���,J�1Fl
�����7���;�����4��U2�	�Kw����K���~���L��H�B�+C�����������\�i�0�Z����x�R��8��W��R�&cB`Z��]
S���~���U��yw�)�4��>8��f�|����9��L����Y��M�r���U�L%��=ym�uRNa(�B|y�AkC�-~�����s�R��+y�DU$�*QP
Hi���=�����be�.-j.��"��I����n��Pp������6e�$�����'C�{B*M�JM�jjX���D
!5��_c���`�m�U�HS+iM)�DZKZ���T�5���y
�AZS���Xc�����P��1(����1�-TKk�H�
5�����I�F3��Efy
YeZ[6��@sYH�3y�*>6�=�6�5��H���I�<|��5����f47��L���@��i��/}brY�E�
����6�d$�������1��J�<������0���. �5��^w�������}������q�H3�q
���.�
����t*����o����,��p��&\���	�p�\$�����`�_��6���k6�2�o4����0s,r��-��pc�~�
��u�����vz{[6�R�s4���t0%�ue�&;I�0V;)���;���;w��nu��[[�T�-x2����_t�~_l�#�<{qG.�����x����d]uBNX��L
�@��+�X��='e������c���+�/2�<��~l+�����"D�C��@������, ����f�\���%u&	�=u��I�\��uj��w]X~�����,I�B��d+A��f������*��R����6w!����{Li��=g5���L�U�!N����������E�@X#�8����i���(�SJi�c�}��1��)PL����{������D�������*1����<�P��Z��[[��^ �������3�F��
�})<�%�W�������i�Fmo�R�Le����S����2�������qC^������X�ZX`��&�Z�N�2Ay�fN��S�/I�;�,�K�O�y?�I���X���es{��[[��^T�ky���4��]��X���e��NO��p.�DNM	e�����$��������Wv)G&v�c�wss}3�/�wF��l���Q%:��<��������8g��o���~��}sg���b���c+�B�������)����Z�$Z�,��vL�[b���?�����m�g
�d��`_=�vu$��B��T��z����ko��~�o�Q�R4��J�i��+���9s��^�8����}����:�Q5R`����h<���p���E�52������h�<�[/q*���A�P����/ ��d6������r�;��f�qr�~�z���W���V���[y��Vy��@
�:JD:::��~|t�&����j�s�E	x��9A�`?��:[���e����u��j?�0����3�����H~ww���,t��q����v0n�r?�������gI�P�.Z2�r4J�m���]"���������D�nGIY(T�-I�.��+%��(D#	�B@n�g� ���+�9,�9A�,��^X������Fumm��������vi,�]�D�[�3�Gu�xi���g��6}6������~<�����>GC�$M���
5��br%���vnW���{��\6W�(%�g�-O$R��M>x)�rd�C���#K��9�+
F�2=mu.�/P�A�����dQ���q<�$�4��f��-���
e�Z��,������7��n������aM�f���A6i�����w���!��nP�<���soQ�!��A�����������j�~MAGD�0a@I� �i�+R�b���D|�c����_�X�}Sr�<�\�	7�"��,��/)>eJn5E���-�h��ICu/����YmgO���&y�~sH^�Z�����JM�@�$m���F�I}�8O��h�#�k�9���`���a^��2�r������n��h�V|^G6���Qr`^h�$ ��$ r����5��RwP�~��$Ms0�-�(���JuWm�c�nd ��|��H�C��x��q����,tUz��g������>K�.qvafS�7E��\N��;�_���$|�<W��b~=�F:�K��g�^�u�S)'T�)^){� c0vF�"f<5x
�Of������h�a��������)�&�!��j����������8n���SY)��"4�5T��. ����t��Xv��l6������#�:P��
)�!x�CM�^�+u�����.mxd�n����"m2}���n��1
C?z2�z����;
v'��;����ns	*����I��_�K:�	�T�o�09�n�P����i(����c���vA(&R����h`����h��@�"���6*c�W{����'U�4q�qh}�������<�D;��/���MV\o�U��B��������-!q�!�:�����;���`
���_�[�;U��9U\�Iq�o�����*���Vlq4q�^7�:�Zx�#8Q��|��;k�����X�)�A���AvE��Oarz���4��;bR������u����	�mb������L�X�l^!Va� �v�yp��+��|����ku�1���7B�7��~|�%�~q��*Ic�4�(N�c��m2�%x�b
X�P�;*���%��bM(n�c��UV�����<H�=*��f�B,�����k�a�B�R���[�+�O�����\�mT��*�O�, 0����-�V�q������+d]�z��"q�_���\�s�M���
��TD��&]�k�D��w�o]43$�o��a����[�s��%�w���d��}�E�q���=8�	���k����z��l[��(���yYO3�����:3-�5>�^�����.=�Z��R�p�%S�u��{�����R�K����($�BKc�P��t��[����s����a:�Y���-�t�_+�����.Y��e���w'X�;#�2�P������<K����3�I8��[�C'8�.����g.[�$�=����c���P�n��[07��c���� a�`���
|S�����j]���~Sq�rXS1���.���<�X�f���+P��$�~�8������$ w�K	��-d�9v��,O
�ZY]��{����Z����:yV�ViF�V6$�C�d}(!12�tE?]�#���!2h�����Z���������I+%:h��}�E��`GM##TN��"��2��hf�.������T�l�Z�nW
|��a�a1\8Y���b����������*F,:�E>X�11�$���m��(a�������0����H.��|���"0���!����'�=
/�E@~�L��kox[��l�:W���7�tn�)]����L��N1�zi�<���da��	M4�%0N��5~K9G�UP�������Ko�`p�����c%#���A������t�c�(�Q_���E���i�o���=�1�+�_� VV����dx����A�b��D]���Q��N����3�$�(�1&���Jr�n����D���2&�����ac�w��8:z�-�"���A�H����nD�$7��(�����	R����;p�h������F��G�O�0���5�D��`		<�#�c��>W��<}���0g�����y3u�:�D��X"P���H���J$^�]@�J�H(��;L"�uZ}'�D�y2V)o;o�����	��9;f�:��D�x�:C�#k��?F�@���^U�~��a�w��M����%\���5����eW��tiKIV�jg%�7��R�#-�J0��R�k30�E���{,%�r�y%-&��D/�=�ad<y����%����tfg{3��v��z[�Z���'��[H��ep/lsE���$��=b�y�~�&�w�z�/}	K�2P�L����#IE�]/��}{�(����K
��",b�W)��;%`�g�._�g���i�{�{�������w��{��QK��(����(~#�]�_�������J���A�	T(�T,.,������
�,��z���`8�/L@1�z�R>�Nl8h�_7r��|���~�,P��Z�+~���� ��o}��	]��H���'-�8��#X`������<��q9[2���#I��\$Q? ���9���"����D$����o���B|(�KBB��
BB��� ~IW���� >�� 9'fQ�^,S�_<���	���,�H��HD<D��p���Y����J��CKI���$Y��H�w����w���^�|#���GR�����lY��d9K�\J[�`�2�fN�g�3;<���c
��|PPQ�!�0"!%���u*�"��h�_��*$�C�6^�oF�&S%b�u �7��������y�I�y��u���z�f�U���-[R����,�F7�Xmn�.������Ak���4S���������h���Lt7���)*as�)**�>EG�-����!za��3��c �����"�����������Q������t;���X��_�~8��3�>C��Yo<���gB�ZN�1����������Fugwo3]��RR,�^�D���Ze�$y
hc��vx�%�l	�~�~�����%.���1��W`����_���!���W��qk|8�����[�z5�Y6�J}�����PV���i���}Qg8��W�}�#��?p�QU�,��W_����p
���f2���o����=�'�_��Z���>�
;7�8)�K+&(�Y��n�jkk{�����n��� �(�z"�����?���3�%��N����u����z���{z=��:���(?j/	o��)j|��9v������"��:��L��=*�(�O��U��2��I�Ex0�T{�7�Y������;�v�'�(�u0k��_cMMX����f��;~���;��Va~���O��?k�t[f�v���c���Y<�6���=���X?�7��oO��W
����h�H*�9,?p$�w��c�2/���������&��e�0�onQ�����Hp���-��Y���(����,��9��~�
w�R�;P�syi����F��h�����(��@I*f)P��G]�tGV��T�{,)Aj6���lU7�	d#@�c1��a[�d]�z�G�2��~����W��O�w@
]����P��q��g�����'�8p����q����\������[���[;y���	+����5:c"�N���d3)��?��x�����x������3tf��u���@��
�r@y��k����x�,KK}�:Z:%����N�nii<��o\^#���fj�EK8\��h��p�@� ��k�����
�
���/Ex���a
�(t������OU�.�\w������O^��Y��������#}Y��j?���������n+��dP�"�+�����7���<��r�i�w�
���[{;���r����������������x�|�����?pf���H%S~�D$���_�0O��0�Y{�n��;�������}�;��r��p?s*�,���`����y�2�:cgxc"���b�3�)��B�s�0���K�J�kJSs�����L�����������������\u�k��&5@����kck��D<K��O����'�#=L�]��jq}�0���f����3��ynh�W}�:��a�Y
pD���V6oC��&s	�a?p����na�p��{�QG�!�#el�Y1@]��f�O&�v�
J��/������p����|G
�U�{�\��CI"ph�����%��"�5��5{����a����Q���H�(�
6#�~�G����,i#�@�Lb�X�2��M���N��U� ',�#���Z�X�3�#8����o0V��?���0����xJ�n,�)����p�F��/S�=�*p��z�i$���R�D�1�X���u#�;l"E"��������d#"����8���0"�&u���N7�^;��H-�X�+��o�Q���y�}������~=8h4��A���������|�j�#.�7�8i-�V�T������jD��c��y
�����T=���l����!��KT??��_(�<�f���9w�l�>yCi���M�u~t��W�U?�?��^�����?=?�oRe��c���+�*��W��`�������<�6�'=�_-������|_��M��_�(����::h���������pp0����V<~��j���F��9=>F��'���}�>����|������%������=?������WG�����N^`�����z�l������>iA#8_�vt���_l�7Q��?����y��h%c��K����Q���9$���)���ct��%���+'�ei��CZ�q~zl~4a1������7�-�h��o����M\����S��������A������w�<l�&;<"��������c�|;���'��x
��}��=<}'���*���p���6�a[4N���������k�r��.���^�}�����q���A��
������T�5�~�g�$��a�M�8;�fX��9k�B}���h�-k<�F��"�v��
_��L�Q����#��-��#"������W��u��=�������"���P��	��y���������[�[����>V_�0�D�7@ti��q��M
P|}|�f���������W��=�	�'���4�����1��%L?��{tr������W����������att�Z��t����&Pzv�#L����O��:j�(o���cuH�.���p?8�E~���|�s�	���������P���x�8�HMN��������o�����q�e�8:���~[��/�����i�L�~L{����?������o����W��Gl��h�h8�`�D����H�zno ?������'�����
�G�~����Ou~�����+�_���
��.*<�i������Vtzt��N�#X�����g��@�O�h���*�T������C@$�{D���[��E����������X�������<?��;��v�=W[l�Z���ln��Wc�6����
	~;j�3�_�����U�����
=������xt����)h��c��a��{�5o�38�������Sb5�3��L��N%B��s���/���'��H���������0+23����6~���?����
d�p�
~������FK� ��#Cp������7Zo�O~�
{G*���^#��_�q���-��T8��
}B���������C��c��LfR��	��L�l����2wJ�b�����I���
 ;�����~|�o�#��9|4i���y�+���?�Y��#4�?�	zd)��3l��#��
0�4�@��a�7O����n2L����=6C�lb�Hb���0��`$���	{)!~
2����#8�ulP�idw�6��YtG�acf��@l�A ��-5���1}�R����)��/y�_�G��zn�9�#��M�������(}F��_``p������<a����w�����v7l!�d^���o�^8�pJ4�s��F�s����f����'/O�����[�����=A(�_@��7�)�.|9������q����%�;��� ����}������:�������~�����2��_,$_������&|���?���8�/�0����������x����@=�����S��T��������9h��F%���a����+�t5��"�W
���f�
���n�Fw��+fF����������}G�8��(���$�BM�5��~|^����SdCK�	ae����hUI~R�����5�DV*���l�`8�^�<�?�3�����
��H�����3��{@�Z(�Z�8�T�k�-�'�6�,b�:��KK|��6RKK�vr�S5����Dk�EvA�����a��CND�	S�_��y|�]5�2��Q���i�O�7��&��IW#P
�qg8�������mq4�>'��nG�H�	v�!}Q��� 'B=�\��(�~F�u3|�%u��3�g��fZ�i�5
���	����#���������[,	[��x��d����p>X�����1�~2�]s3�����b0�������HZz��$z����e�J�h��u���
o.� ���}��?\
�@:=�����m�:7���u\��M��
,tO�e�K4��X{�XgBRx��K��lfo��$��G2�������Z����u�%�G#�mg�~�n`����x��"!$��o�%H��9��_0}9Z�E_�L�EWR��2	����m��#*��)m�������B�}XkccG��n�*�D8:D��/-�~�k�/U���G��6�L���j��W�l��-�o��Q��X��#��/�"438KKE�5��g�ib"m��3�3V�'+^��
,�"SK�P���T+:�_6��-�E��G�%J�x�~CJ��'�Pvo���P"�j��j��6���p=�Y?����qimm�������?e%��sV�/k����
�/��6���W�$�#��Hv2f��\��B����'a��_�;a^�	w����%���a�Y��:m6�z�(��������XQN!�+����r��	8�]��'��C�D��%��)��{)���)�����������H�_��&��|`Xx��|�)�fK�s�9z�S�jk��]�	�����y�(���#>�	eRp6�������l�Q�N�Ey����F�� �NM�r����H�������d2�,"�Q�r:����C�q��/�.�e�V_�C�(6�9��g,�=�!`���K��//9�N��������0.6GW���o8�B�X���1
4m��7_�G��s�l�
�������z��a�o����K�U�x��[�����=	�Y]��mZ��
F����� Ry&��z]������G����O���|:�=�7|�\Sq��pA~Fw���d2��a��T�X�g+O�����Y��%�!�������'�'�,c���%wZvbO�O���{���~�Di/��v����m3�%<���rt0���
���A
s�v��Dg�qF���xL=��G�`�@j�D�b58�~��,TYY�r��j�O+a���+!v�8��5���@�)�L��{<D�G6#f���Z�����T�D������qU�4Cd��%��_�8l;�9����K%�pN)y>�m�3B��6 ��(��i!	tn��!�p�9�2�
�����&k���28RBl�k�Q�R5�;o_��>�&�K�g��(9\���R��[�����vt�;���@��Q_�M���q�`<<�tc���=D\�N���D���F#��������'j�������Q����P���ib7��p�r��D<�������at������`��L�YErO���j����1�I����5V�h1�<{
�\O���W[���y�cV��KxW��?��F��W���&����{N��)����T��3��*�!"v�#z�z��W�~��%��n���n;E7jQj�
���C�s3V&�zif��
���,��@T��%7!��	!��������gT���tn�(��YV�q,��8�C�l���h�T<�}q��D�W�)�����#k,�H�\h�C5
v��)n�ZH�H�\)�W;TjV���u���x�Y�8������.Z�����7���l�o�	ND��Q-�pV7���B#�<���E�{x����L5���^s���{
[R�$[P�� �42
K��&��e)���;c�e���z�����$4��$�	��'@p�(��^}�g�O��������6?i�
)�G9k(��R<�x:��VJ���p�/0�]���V�g>��VA4���]���t�;2��+��Nk�8�{b��>\�#��G?������E��N��q�B�al���.������m�N�&�!)��<����
4�(l�,�]W�e)y��g�;�o�hXPW����y�ZQ��V"%1��6MF>#F���y �*���d��H��Lpi)1K�����$+Yu����p�zz��B�uV�/&�@D{�ag���s����O�F�"ZZ-%��Z�����_zY��~��Yq�h�+��d�{�q��C�J:O���x�����5�N.G���9���S_?Gs�f�D�F�����];��FW���O��F����i�"���swG�-�WHY��8y��RC,��_�\�k��_<:�m>6q�M�y��~>�S&mm�`(k;<��,���btO��_�@�+��}����0R��h�u �ub$*[�*^����]���%p���^P�f`���>8�9�}m�����i��Q#d+^2�p���WB#/[-/^9)���t�9�*������J���f���RQ���!���g�a?��g�w&�`��_���5��EiM��P��M����'�����151���q���!��c���Q��V`���B�X����9��Z5���Fs4qn��d��:=<N���MB�����c����f�����gN�J.�C��T\����J�L���,sv'9�:3[�����{���}����N��x+����3W�`Q�21qd�Y�;�0c�{��
FA���A���Y�M���]��ld��"��>v�!(��]�=c��X���w'��k��J��Y�������,p�6���������ne��Z�aD��lA�EE��4j��E,��`� �'��O�0�����g�����&�6-@E!��h��5V��5���G�tn����P��MC���:�a����&f������Z]�D�}3�T�B���m�M�
�iz��Z����K�I8G�K0���F��(����u�y�`��@�^��s���Y�JYf�,k#k%�uNb�=����3}=Sl���D��t���[Kh64���Jfi2z�Z�d��������x���Y��<y�����iz��r�M�#x���b1o�0��Q���62��M�Nm����:������h5e<��E����Y�0���"�����=����^��u��S���O�G_1��L�����r�?�(���0�7�uS
��\^q�7���Y���&��#��]���kS�����}~������F]S�$��������K��[�U.-}@�L��Pe��Sf�G��q���/��/
�(����A��O
-&���o3�v�6��w����vt�z:=V�yj0W��?-pI@-�����������R���R�D�����)���n��BK��l��������>����R�&��#� X��^����GS��2����v.Dt��%��J�
��� ��V����'!�8������n��������K���j&L��������������~�,g��W�LV�������'u:'�F����-S��N��$��_�S������sh(�'��Ukj�*�	���Zy	I����4�	���T��jg�bg}m�S��n��rS�����*�rB"���D�
.Gm�t��,��3J�=�I�TNxK:fDww�+�����Q���XC�z-�d�@�!�tSU~���u��lOPG�����=����7:�2X����fiueH<@m��?{Z���%���;�������N�b}���K9�/�x'1�#7J���26����Rz��Nff�J������*2��{^���dk�@�5�=�w����h8�
b��$�i��i�`��0C��Y�f0�F~/�����������������w�����\�����:�[�	|m�R�JD��\j(a��j<�������N�	�����F������1�O?EO�sL@n�h�Lc��j���JDOYq��B����llH�����&�L��(��S��m�j�`c���'�����/�=KHX�9-a
������6�-L��]�;|�rVc�����D#�9���nOYo�6fY~d�d�����d�n�J���=@� G��L����}<�@Z�	����V���c0�GV�����Ph��X�DW��j���
���0��JR�`[�5%&�X�(����w�����S�Y��7��&������b'�������ll�/k7�Jo�����Ovjm�"=�-�Q�����-<���4�HN�p?�����&"No�(���Y�i�te�J�~4����P �'G$�*��Vf�%�"��C��Ut�,A����x���/G������=���_����p��V��2@���
�Z+��g	L]��L�H��
K�<~A��7�������C�e��gr���8���"���)� �xT��H����C?C�	H�bT��>�I�r��^"��9/<+<�����h�vQ�4.��#�����	y��4�t�@�K�{|Q����=���F�oD������t�s��n��3����'�m$=r�%����`����1���8VROu_���&�L�f��d�E�D���_g��Wg��8�j���_���<[�z�O%Y�
.���`*��	�����U���mg8���p,��C���8Q�\�k�:����\���V\���@���y���}�UP�6����p����_�$���~��}�����-��K�P��Av�
a�'x,E��������0���]HleAH�U��u������w�B��l���Z��S�^ ��]���q~�h����~���E�����&���Z7t�)my=��KQ�d���l��z��������*/�I��(��L�T�`������(�fl��S�ja�>P�u�(�<o�����t�6��Q��;��ZshHt�tG���,N��������z�����E��@�q��V�dsp��n��Q<�L;�%�����x'yp�(���lnBK������P�h2l�#I�b�\N��a��YKK��������pN�p0������m�c��5<nD�
����^oO{q{>�q^HH�g�;Ym�h�H�����������X�%�>��6�����2���SI�]�[ �_���3��/k��<����Mm���}��%���s�X$:,��{�PG�����:���C�4����=�m4�\���
$��h���$�^	��D���0�il���_4I�HT��
��>O��tE��o_��j����P.�xHSP�7GM������N�Dmt�
��+2
?E��}�u���I��8��<N@���3U�}zC.��\��T3gm�����WI�(��j���o�vR	���c�
B��D�!�\uC�Q|q����$���K�[^V>�d������zh"8Dq#���Z����	�G{����KX��o�i>V�U���
H-0�����s�D�%�_���O���%�l&���O(��f��W�G�O08x�I����(�^�c��:�
E�8j�P�8"6�~��O�i��M��Kk��~[��g�(`%MD���=�Z"k�	?�����VTt��&.�'���^I�PZ)�I`���t����]?���;=����*AL�����>@�^�>=L������u5��6�}��`E���*x��N��r�3���sa4��\���T�j������|�,G�h���]O������5�*�<JO����F����+C�:��4�i����L�-�#�������A����f����]��b0�J������������r�9���
h�	I�`�����_`b��V��wQu
��V���mh�I������~�<�n��R��.�$����1��qH�J�g��[*S�^�#��=x��i�!��E���S�����K;��
H�j�xQ�\� U���!�@M4z����'���H���;NU���������Y%���{�-�X��m��'u�,t�.�F�+�8�v�Z�*��hIG���|oFF� t���>�:��u$�\���3K�"v�:=���HBw���S���@���Vz����faCp�,����ft�2�O���\�.�<���8��U��@��<�%I9��������P��$>���CB��J���V)E�a�7?��Qo�=o�1���3lbF�b��*q��"[�G���!	2;��/OR�`�zY|�M@��Ah�	8�D���2E�?��*�D��f�3����
�	��D����o���M
�:G�W����S�j0���I�CzBwJ�Y�[)�k'��3�hX1Oo�u���lZ�%	�5h�t�)�K��Q�?r�?5W�pm
h9�_���l0���s���)]+&
�p�EbRDG5�
��T��R|�J����t���RB���%�a��-�j�I��ywM�� �"��!\�}"�?�KD�������q_#����
3 ����E��V_
_�|?�u��z���Hrd�	�e�{z02B@}�0��\�		"�����G�4���Mw���Rj'��${�	�+n����������s]jY[]W"{E������+�U�)}
R�a����)�1�&s��|����������BF3�0���`�a����
)�|�B�|���~�6BB��0��
��N�f?��.���z�Ql�?D�pd�	)l�����-Z���z�����(��E8��0"y1&l��V�y3�d�aNL��4li������b���������e[D�������k$��IiY���?���k�4C��	�����L���iEC�5��"��,����7�����C�l"���E�;��L��7���w���U��rVi��?����?��)��O��S���u�tR���Y����'�#��~���x����	���m����P�+��������BM7�nl�di4Nw*����f5Q5�C\P�	�mS��eO'�$��6�g%�u>L8B�'3��3�e�gz�_?k���qc�#���S�?�:B1/.��8X#S�%~z@
-gs�p����{b�����4}�$�k��o�f#��1F�����������8a0E��0����F�'��!�/,x
"��Xa���]�jj$��0O%��x�~wq61�d��A����<�X�8�:�3589�6��S�2�r�����lJX�
r<��]��8L�d�O]�� ���=���.loXR��2f�=p�����G"����2��#�p#����2VD���?j(����a��.HD��%y��PSM�; mhJ�O���_������(�7�Y�����-l�������%�Z0�|��$��O��?��k
��{We�K��5Z2�#m�a�����_�=:>�'q��G�W'�������4���y���N��\�K�������;�DV�

�X��v��S�	��-ps�b��I�`��65(����7�(*�o�����DW��~�_�9�:��wb;gc���Y�<��D�le���82�����E���|�(T����6�R�q�d]��R'�m��#���^��b!���w8Lw2���y�=�����t���f}�5aR�B�5��s(J����-&�U�-�N��]�-@u��Ag�!~�K�+n8��� ���[Uo�l�13`��xxs
�������Vo�,��J+��l�������-F(�F�M�7�����B!����X)��-K��mz"�.B�����KQ��%��^�&S��O{w3z����RzgT^��,BE���7�P}A\�_���J�B`�������0B������4v`��,^^�b�x���!�jvpd�3��LJ��/��+v�HGi�T�Y�6��X��15KK�@����s4/u\,���E���u��c�N�������\�V����lC���<p"��������Vo���?P�;��x� ��>��'�������������'7����b�������h}%��NQ�D�*d������,�T�������@1r)Yw��a���VR�O��$�u����^N~���YR�p"�}�F��o
�O"��[����F����@��%�|���r��F�yj%c���}����������V���D�^i������������$59���u��%>@����(�<b��p���������mG��P@	�7������������V�X��r�n�C�I4p9����G��F�tH$��0f=���#�F����|���c2�����G�����?���'z��GO?H�}�E����FEV_@[j6��X��&!�o����3&/��a$�h�d��G3��J�r��a���V���� ����*,�����+f�t�\5���WS�I���[�6b���-�c���rk:\c�j�/R�!����,������u���o�V~S�'��'E�����7����b6I 9��&@O/���h��Ur-�p���1�����3�R�J�g���������5����}�t�����K�&�g��K�}bc*����}���BG��L	d��m
;������m�����������\��5"$W�/����O
`��d�v���	�D��X�n;�A�?������X:�N��~�o�2�o�n&w�l2��������#�O�k��zpyEG>���W�Y
Z�x�CU�"�0<?�@�=�Y���\�C[���X�x���-&���_Iz$��haPc��JG���h��>�Ta[�J�K�Y���.��8:m������D������9�`*W�a����������76�qHm�p���
��������/"�7�mQ�����&!�:���W/�����Y%�I���^/L`�38>�S������������4i+ ���*���h?��#������6��8���5��Z�sEKJ�a\�\���<��0���v��V�,]2��+Y����P;j-U����3�<H
��|$���+N�`4���b����CQ���������F�e���/���ZF�(��`�����2��D�K�)jk������]�G���*�o}BY�m|�}��v'����N`D��3�K<�/7-�Y�`Y�=�y�o�����Me������R����1;�X���Y�"����K����!����yx3�d��;�O6������C�	�����5���,���SP�������["�2P(2{]�4����������}�.���b&`�~�U��G���:��P����p�S���IB{4�����wp������Vg"4��Q�OR��;)���4�>G�V�V����]�8\<r��|~�`�5�gEV��	��x���>7�#L)q����u���fn�������%�>$&�W2T�OB��Y[��f�!db��cM��D|8'�AB���d����M���^(�M����o4Qo���BqK8��Y���i���3����A��[s�M�5������a0�+h��x��(s���a�R��R�#���)�<t�51�"�D�������[�F����u��i���
�bL��&�4lu�(����!����d�z�9{�#��T�E�{�p6�#d�j��>���Jr,uy��2��	�|B�">�EkG��I��:��F����o�Dkkk����33�����Yl�kwZ�?s��T��/5W�,(���(�|'�(�KI�^K�'}��9���w\Sm�I�6������XU��\�3�o@����|>"3�p���0U2%+�@�g?F[��W�Jz���i�1Q��e5���pi!!���Z�	�B��s�u���0u-0`��sW/��T25R�R�$.A
8|{V{HzQ,�*M�E���7v���u�KL����A���#Xb�l|_����<�Y���W���nv`����*=��7��������%��t�����VU8�N]}�/�'Z�����`�jKb��4L�Zo���y1��p����v�+�be�����<SF�����C0%�	���udf�[E|��(�����>A.P�f����f���z��_����k%���F�AW���+F>�2��	��F0��)����RV`���TwM����9����V��D�O��y�o�b	N��2��p!/<[���x(z��:�|�1>�2�'h�zQR��y<��`M�������\����~Jn:b��xN�-��Q�p�cW]�n/���2��r=�����P6N	L�hd/�z��g��y2���Zv��6�F�����j�bVI7k1��>g����ky%]��q��#.��a"w��T��|����U�R���j^�BtG~y�.Xu�b�]�%��C�*e��\�������kSRO7�V����X��b0��@(���[NDg�a������O*5����*�+M]^����~(��~��'������������1�s�g��,���@8���E�j�RRh`��'b������pK��5�O�|9�O�i�ISml��k�����(J�?�����C�j�XT�k�Q��E���O!{���on�v�����5z�L7��;�����")\��Ov���
�����������PH���?��F�jEz��Nt��4���"N�*��5<� ���+��;�@v���s�w�?uT�����9��vcN�
�F4�'�`�GQg$A�V��#
z��_��0%����qpz~�"U�%�FI�O��������Q��^���M�����Q3E�Q�y
�0 �FC�E�^s
�����h2/�n��E�[��F!Iz4���=�P>s�c��AK�G�A%SJ<O���Flr����h+�]��?x���l��	31��8?tlr���#;�[��5�@�m��+�im��,Zj��]������&��"-X����Jz�h��vL&P>a�$Z��I>Y�h��5�T4��O��J�|�����o9�����*6�l�&�40M7S�%)���V�w�1��D^�`&'�l]��R�MM�dw+��s�x�ib�X��N�`B�f��w���i<!jm���������o���pv�L`�4RRD-�\���e�&���O����� �����T��1����Tl5-��U�Q~�K_�����<����R�~�&`?K���E�H���@�r��"
�+��Q��L��L=�
H*�T�?���FP���^z1��D]a�=�o����Gj��1^mL�>2��I	����I�8�e���a�h��M�h�9�'7C�0|[5�!r��wMg������|�����S�:a�C�uS���f]�|CDf�Ck��MuJ���V������!�l�E�t`�{�i4������\a
�_��o���-|/�������s�X�y�Y[Z_*�rl��#���\��A�b%�K+����3�&i��y���Vh>@�
I��Uh������UV�zRq���W���}iU,�I�:x�9����h�zT��R/�~4�.e���
�)O��(N
�4��%�������3u��"j���if����i�Q�Z��4�U����/��U{���u�n�n�v�^���,��=����A/���
���r,85��S����_W���eF�
'���_��D�����O�5���������Q5�N��b
6JH�k��r3�r���>L��e�U���E0O����<�0��:�g�Kf��G�a�Q�K;b��:��f�,uPpq��^�Q��l�{�������3f��C�Xk���_��`��?F����zmkm-��m�^�D������G���Ezz���R����/����ve;Z������\�L��w�~��P��&���)��D*�n���a��S<��KO�{��k�����>����5���&�:�0��6,��e[J�lB�>���?C��'Lv�:�C��_l�S��A�7���s%�$��d�����`��){|y3����t�3�Tr��2�eu�j�7���S��2o&����Y�j�&X~+���l>Ki����#+td?.�����}�7�fo�W��][�vw.�j��6�4w�Oes�6+;�
���}�(������������_�����-|�h�Q|*pn�~�c�N������m<�����Q$	��\W0����p{�M��wg�i6��1!���nW��
uaY��>A��/�4Q�="�%��_��7�d��Xt��������0:�"M?������L��1�=�G��+@��}{�W�*�o[�;<Ykg?a�-Z�c��i��Vv���Wj���������~|���b���j�������~{r��5�\Bm!3{��
�0�B��$uP�QO%_�u�������M�������4	������F���+�X�M.c������g��������_�ov;�����fwcg��N
$)@�����
 H��F����x�{|����0$�������
���f�����.An��{)�#�M.I��oq����l�Tj�)�l�(�\�Z������6�g�H��wh[�0���� ��i������h���E�����I�3_��ptr����4A2����Bx���&j�-������-��"?���Fcue����b��e��#?qL�0�:�Um�"b�����'�f�p��a�(��1�&�����6*$0��X��`XI1Ma�2�5r���u�V2�Pa
c�<1sj��0�d?QK��Z0!�C6�G8.14t���Ma�]���G��'��[%�u�4�6����
/�{M�=Yf�[��i�IA"2D~�1������t��>m���Jv�^��Q�wJ�m�'2���2Z�wN�m|[UM|��dPrB�U��M��S#���*���h8�$*fS(<���q�Q5�������H�����N\t�2���B�'6������#���V�%m����.��"��hw��\Z��ABA�%�a�E������r=�;�XI0}����C5�5rVvd��=|
�PTA�f�t>�Cy����^������a3����g_CS���B��$L�����M��WKQ���7/	����~�kS�������Lq�	
KlH
�U[��4�c-�M����7��=3�WJ�c�
f�� �=b��Y����w��N�O�K�"]PpC��`&!{�1 ���0��B����z��\x�H�Ghs��Os���.�7�������j=r��G��b2��P��j:�>J�`�(
�;c}����Q&�$����o�HH�r�+4R������%����\�F��o���5���s{����2^[��8~\o8��� �U�:d��B��)N%�����������j���T����h�R�qS!]���b;��?������m�n���8�cB����`���t��)�;V�yG��Jt���&�#Z�U�9�#��dDL9J���#�"&���m�DU%����{�O%.UI��O����
�C���Y�o����d�K��dPn�<Hc�L.>��j9Q9���6v:*�T��H�	�P�9��G����B"��rz����2is)�&K!.��%D��Vj��Jm}����/���r9�����%)�'��h	ZU�P�wt�x���w����.�:��`��,J��o3{��~����v�v�����X��1z�\�+n��6�������C�=u��yD�zu�C�%��$��������*�*�[��7���7��>D~��ug�����p�t��o���E�*�yE8�l�"w�E)�KM��������bR��(�y��n ������lhTfo���7.�E&)c�����}��5�tJ����[f4P���.v��pr�kY/��76H���N",����t�Zg�nc��2I��+��h0g���e�\nJ���.�s#�����h��p����-,cRZ4D#������.b�����~E,�?��a��"���B�3�0��]�������i��M��<k��9`��X^"9#L4���J����FI
^�Q��]��<7va2'�dG�W�!nb�G1���6+3�0e'���=e������Y��Qu�i���1�%��=�i��p�>��b[ _OW��c����V����Ju���E,a�t|3�Y�������1��t<�g��|�oHo�H�A�1Z�5�p�:�q�b��U�{U�g��Xw��4�e��.�{�@.A��W����j
	[��T�?m=
���.4b1������i�*H~�Y-a�KxB%���T�d�s�u1��c���x�hCV��~�l�'�t,Tl�
"�0��7k��q�pS�F0������E9��#��������7�|��������%)���]�X����i1keG�2F�`���8k��������w>��)E��.J�>�nm����Jd�c��*!g��F
i����b��$V#����O!3;�>I)�z��� �a�RL$��ZJg]V�oL�@)<��g��L�1V����`5�������h|
:�/��.W�l������v�&���#�Vm�R�V��-/-]���$`����	��Px����|��Z$UI�K �V}����{&��4������$�:8=>=1���M,t8,
f����;�g����3�b��g�U~�D����0��~�[�JQ��t���J@
{k��J�]w�����!�rlM;�d���&�t~']C�!����<��YfS��`g+�E��A�Ik�����*�����o��Z��&��.x��
/]
.�`6rFJ\:���Hz*����xx����x������MYOH	�:�-~`v�oX�ug����`��J��P��~�2wo������]��EY�f7@�~%z��lz��C\/�S�1�\�����mA�S�%kdR�"��-����l�G}�g��:���>\
�qR��P�7o�ZBb����3���P:�b=C��%'��A�X�mx��Sf�0�}	x*�M���������$��EP;��^��xuU����B��]��]��D"��(���M����c��\�;JBA�q�VJ����?����s���O:iGR'�?�+c��a��H�=�3d�I��
�����-A�\�5�����N�a��;r*[;��l�l'��`���X��
�}1>��><��W6$@��������&x�4����E�4�p;QV���:��]�9��U<�B{�=���<���#�~wb-��Rx,OQI�<��
�W^#�O�mS��T��tQ��8��#�-�,������^T;�i�������FS����BN�~V�n��4�m�����N�@�*�E���4�n��c�l^�&<�=c�y��{�m�7�n���[R�<M�)A��9� HQ�_������-��\�6)x�z�V��X5�������y��q��D��n0�-�Z�'������g��[��[�/4���s��%Y��	����K�����������k�L���(z!��V�Q��J�����(
��|�*[�>����SZ�'�O��E���[E}���Few` ���q8u��]�� �������t�y���I������*6����!��dM��y�;����1���l���K����c���������stB�CX|�8;o4'�:j���R�1Wd:
>��>�B]
fg@�QNk��G��P!d>F*j����t6�P�U�������'j��]>���s- E@��`�S��T

 ��<Y�~�
~�=�T��������]�+�by�������n����O�Gu}�����l����d*&���.Y[�������]���Nec@��S�����`��?�w��q�����w��"�uX�j���L(��7�������@�� �=��4��D@_N4��z����%���ldA��Qi���r�5��ek�����Dfo����@�q�1��,P���Y������{�nH��=o�/�����O�vTp�q��
�Kdj�cu��p�����~
>�V�����zW:�@t��+�k�r�
,�s5����Fo[�v���\���c�1�������X����t�L�w��]b}}g��M6�}��{X��P ��)%�!QZ��8�7S
��p��cbb�;�+�����y��y\��7�������V�<�7�������ZW������e(n���M�y������w����������g�0�`q��4E�.r.�R�vGrr�?AW���SMT�6��L���{�UFp��X���KxzQ&'�x����
�������1V���	���1��^�x(���"�.����Q�R�p��.�PE���3��:3���j�a��8(�W4���	���hM�|f.�Y�T���5��������N���e#��|�R�4�ya0=�����K�Uy8��KP=�|��|�����
����E�FK��%K�����~�����i��E��,�`wY��/�C-U�B}Q�M������
*1/�7�>s�,&�&��K�����CCUIl\�moZ�����Q��!��������X���Y
��
e|��f�K���*�/��no�bH��l��A���~����4��gT���7�h8@V���&u�=#��G�l:ry�����^�R�k��5�����J�$��0��k~�C'tq!�t�/�
U����nn�hSpQ�t<��TD���h����R`���������'��&*�n��J�������G�'V�Q�"�����6��"^@��Q�R�����R�*���g�A��(z��S|Tbs���)�R���-����x��W�A��c{��A��%H���oJU�2��S7�V�j\���;�f������0�1����G�ag��eN���&
�+F(��1r����"�8�*��Q^a������5W�*�t� ��	.�Z���)��S�nh�~de�ou��u��/����������C���-�`����N��Q��H��R�m����.��]*��������-��z��w;�R�C�z�4=�}������"��G1�T������
���R;Ty_�I��u��D���������Qu[�S���;^���WeX����+a������v��5��7����@y1��,PZ� �p��i�z�_)Y�l��t��GK1m
<�'��F���f-�&�Q2��)�f��[-+r��f'&e9�C	���m���S���y��mk\�*�]�������vY�j��<�����X&V_T��x|I��c+����*"���`k�7�C��Pi��#L�7E�$��J�g`<�m��������Af��M��h��$�F�����_|���j����[�����������e������~5�ZY�mM�����=���S��
�[��N�N���0.�h������+�8���#9 c$ �-$J-�^���j^k`0����)�����	SF��ae��i�o���������l�v�=���3KYQ(��|��Lh.K1���)R0F;
#]������7�
���	h�2*�G�k��a�����j�d
/������rIiDtF��o4C��iCxw(p��j���x�j�(����JMJ��������T?��\�E��l�w\>?�����3��U����V���T"�wE��'J�H����[
��-�?4~a�]�GK�L�7������9��D�GK0���8� �G<#��b������s�����9����I�Y�N�`'+�����[�Yt��r��{l�K8�H0���D��8,Hs�k���s�i�0�}�az���\$�R��c3�"�K��j������BP�����V��������������u��r�W0��,��o*�}�X�F�m(�Td���Qx-Hg�����2XEf�bDi]���2�������VUt���6��+�����+����jM^m�oU6��`����~^��Qj�����%1������a���E|�5a�q0E	J��KWEnG�Z���f���>�0��E8.��q���+���r�$�@�XL.�2!�W����[4�o�x�az�xt)�3���J�&^G�R�`�KN|���I�mD����+�SE��\�� L
�M���c���
*�%1Qx����F�:o�Jf"�Z��>z��>$��Q�D`�;j�[�fc`���B��b<�/+Kg(i^�PO'�Yd�=Lc��Hg���*m���o����XCW4(,�pf������{����v��PK������s	�d�����h����xrGl `��R������GRHWT�}Y��������-��������fJ�~����(�����zD����}��}������^��>-�����;����v�\-
^I���� aU����R,L/g|����8�����
����+����J(D���b�����`����=���3�#�M�xyD��
�~C����`�7["���,��0m���`�4�Z���1>��D!�l��ZrI5D%Jm_�����1��yuj��*-%[��'p�����?��$��M�[�'�j�'�,�	y����|��Q�QuSY��,�0_0w����7Hxd_W��,���3��\�������<���p���g~6��rn#u������+��%�qM���`H�����3,S������UW��	�_��dgW��JD��e��76TWM�+���eN���8��I�6����k��
���@���3�z�T�)~%)����?�����| ���2���&�>9��1�=�;��&������O����;Gcg���	�f
�P����7+�Hx�,Fx��0q���"]�wtU��H��~|	K3E�OJL�PS2)�3���=[c�b��7'��hLgn��*�x����/��k,�/!.�P���4pp��l���;������E���(^����,V5���]����V-���@P��Y�p�wC$�� �1����� �d��x��=��no����������:y���\�.Y����7,�xfp��#���q*s�[R��1_�l]:�U/!fE;����m��`(���\���6N�fa"�l>�|��9�t��������WTt=!�����Y3�hB���I=�W��mU��$D`F(Wn�
m���Sx�7��t\�8#W���9�(��r���Xq,J��	|�h��Pb�Ld<��xHQL���H����l<�
�C�,�4���%9�N_�0X��3h�����h���s@�5=�3v��t�ll�����
+����HY��L&�A�'��W:���z�����������NL�
Y���oS���e,C;��ZK��V�������.���&�i�F����[
=��'(w��%.������l�-�+V�%�CCnP<����`�QK���_pD��������v��x��{-8������h6��}ifP�Cg4/�z���M!���>�d*�4I�'a�( ��J�-&����R�`�mm-�E�t��h�B2��}���A����!�t����e�O�_������'�v�4��U�Y,�=��n��5��@	���$��P9z���/8U)��w�i --��(�����m�Q�����v���&������#�~!u���o���
����/�g���x9���[���,R���D��Ul���h��}�A����nX	������O%{
�B ���%%�,�p<Q��Kf���B}6��}��:�$��nA���S�����H|i���h���e��:��lw�p��@�������{�,��,�=%Mj��Y��>x+ye������,���k�|���U��Y�}�VW���^%�����+���zq	s��T-�������C�An�l/���O���c|Q��>+j��x�7����^i�p����x�>v�,1������a�U/����y���v���v�����EY���s/���i9�v��A���[�\����:�]��~J�d�K,�X{��m��D��j`H �1��,�-��pwc����`,�_l�qC�:��y����<P.�6y1������j�v|�������aT�������d�;��b-���|7��P����Z�����
&�@xF4���1�6Rn�D��u����0k�f�F���7��$�o������/��}"Z��5W���DQy��}q7�7^�k*B5���37Y���=��~�Y���MX2B��`1�K�G�$�#'�
�|=�����*p!�'���0/AX�C�b��3���TqPP���@?��a���5��?�X������Q�����@@�1��
��DlQ}����1>�Hm��q�P�����N����T���`�����R_�)"��e�Et���6���6�"��"����
�K�d��V8c����7O{ �I��)�>L����$R'N�c���fh�����'���������W<�
}��U���w4��<��������|�"�\	�2�=�t5�@��L%L���U<�oF��f�yL�
�RO��Oq�1g|L;�_(��0�����^���h z��	��7 "w{��v��������:T�����������������/+qde�	�4`�
��W
���F-x~V��J���)kx��,z'��%����p��v�`�����N�����}lEF��!���a2�����l�3�0�GIy.�\]�^Fh�|������Sa����N�W'o��l�_a0��
h����q	��G_�G����x8��A�|3�����������U�F��w��8]����`n��I��;V�S����N�o��4��up,��%	?M;�����rEZZ~�'Jc\�a��O���%����o#*"�1������N9��=�R�4��������p>�qB_ BD�x��p}Jf��$_a�4l��#1K&J��sTm�U�v���$�n�"� �8=��+��Y�{�	��7� ���B���_��D��^Q�O'�y����m�(8��fA�:R�=�Z{�`�����	��������2�YF����4M�����tZ? ���A�~w�jv+a@����~���}��5a{u����
�Y�q�A*�u���Q���1g ��S�I'������x��\�H:�b��)���re�~	O��������u<�������H���`���,f�����T��0`4����g�Z.:����w�20T���@&�T
�����[���{���WRe��d��+���V��o�IpO�P��������F�(�N<b1��9��Bb��I��%S����t������j���j)��)��N�?[
f5A����,A�w�(`�f(���U�jl��G����3���&z������58|q"�:�%&�)�V��4���3�������!!�>�xx!�f�P�Wp����p��St���� 4i���0r%��2�e����;,	�w��uB�R+��a#�������g5�d�7�R�����������^+VqD�hq���;=]"8?4(����/����F+���7����I�����;�+�_�V�;��������{�6�0~���4����]5����m�Y�"��1����(������lF�[�$>T�������
�{�����M�g����g=�v�fN�[��k%o�0�:�����7Hh������z&�8�5Y�]T�Z
V�v>H1�V�p,����#?^�f*h����"�b��Cu�/���pX�Pk� �p��'� D��z�)�����y������0��"����Zu������h���$���TZ���I*O�99�����E���Q���h1O9 ^���������y��E������`��p����L���6�p����9�p�T�P��B)x���r��N$�b�
@���!U`����X��^q`��z��m�<��|����d��&����{C���,\|r���|M��e���A��{�������Tdq2�(�	�-���/o�|��C�sk�E�dk+�J����������g��
����q�p
�������8*op�(��k?�L6�'Q������,L3����>�:�� ��{�'O����R�9�0I{I����W�U��H�lZ:�5�~�u�����.�Ti!�����Z�b�d(0U���A#~���U�	D4��~k�mK�*��QB������F��1Euz)��|�����C��>�H�z.o�F��;��W!9�M}�};���29�5��Sv�J������|C��1�b`�v�`%��OR���F��dW�����Xl����h09���7�Wx�1�c4i��Qh�sI��
?�`$)������X.�J����=� ����0�X��
���x�����H�����u��X�1B3jS3��eK9�_V�-��G�>l���G��(��.%c,;����
�H����)Z��X\�hiu�l������H�3k�d��c��s����MJAr�9�0M��j,�1D�Rd�uFfv��\dz����Y��?C�!$d'�L�h�z-B���/�d�F���V�8��8���@g���Ai��!MOF�������w�7�n�uZ���U,P�jRO����I�$lN?4��/�{&�])��R��'hGhV����)�5��=4}b��k��e!�������`Pb��-W����w)H���co$(Dj�{�<~��`��_!d.HF����H���m=05�^�w����s����26m��f��B��,�Y8�`�:�A(����t�j���-j����>0�,�&�j�F��'�X5���c��lD���b�|.B�R7a����=���x����l��{)�;�����.L�M�o��
�R��bEOo�z��(�3��F�	���p5F�i����c>�H������io���=9��������8����l��X1D��SI�J��{�+}et�O�=+
��x�6��H���}�H
k[���N����X����Tv�&�)F�~�.QM������_s�/)F��(`���x=�_0+�G+��*9����!�p�a�B��,�16���v)�m����6&C+��W[�K��~�+�/&�1l�X���a�h�����<�hee?�����q)�K_����������0S>��Bg2���=��R8��)b8�f��diDt��'���w$��k@�*XB���
�5\�&HK����0�������������I?2�Y'�~|�|	{���a��
6��u��+���jY��EF-��5]r�I/��Cc��}���A�q�'q�gJaT�5m�k�6���^Il�;�N��d�a��!�����A�X�-�bD������T<|x�H
#UqG�������z-E�y���z�Y�,%-O���>��SoHG3���!�`H���r��eQ�^�v�P�)HB����A�\Y�QR~'������H��^�`|�Bm�.�����M����
:�x��z�D]y=��M��&���5R����f3���df@6�63)Q63�.h��i?����v����a=qX�d�b���h+���<P�������W�f"'7Q=���vR�@O��[ZN������o�\�F�XK�9W�r�S2H����ma��X�+bI����6
���LQ��`
H)����j�HsJ�	Wa�=�*x�&����R�L��l�;��A:���"�?�b���{�P�������/�����	 �����C�5&E�l��$��}���������$��a_� Tx_m-G�,(z
o�3���K��y����Yk����5!��WU	��$�e�r���F�Q�
E���_����9e��Z�cm8=+�Nd�.�Iy����2�7��P�j�EN�A��BN��>�����:'��;[�vB�����J������fTBl�<��c�M����<�.���h~Ua��� 0�}!Zo�M�����A�Y]�
������'��}H!��Xu�q��|i�>C��n!����>��� b�C��ir9-�[KR-j)���$5�5v����T���/�!B���u�s���g[&�eN�Y�U��1��;�Q�=7�y��w�)�#v��p��x��<lW��H����w���w�1)!Q���������1k�l��
�.)!@"�����di�$I��
0�#��b��(�R��<�_��b��2��&���h�>HYJ'��w����^�2�r�^&H9�Veei�Xi���*�A��X
4,y���{
��7(��'��s��d�%�(�,Y����������I�@^������$��)����>���U	����-����6��N����f���l��������$�1:C��f8,t��)h��h&��Z8%�'kI��o�*����[����&GC�e���^�k����=/��)��b�v:&Q�x�*����6��L���7d�8�gc)���GaT};�:%�[��Z�E�X��]���n�9�4Q��]��!�Q$��]KJk����C�]���'Jw��lGk��)����E�d��$��o�l�*��j:u`W"��8�����h����*p�lt�2��M����3	���@����#VNY�Y������(�YJg��Wy��[a���/����VW/��u����g]8&an�n���=������v�zQ7��#bn����f���m�nw67;Qu}}{s��*��9=<ZYY��$m�0<��R�C��Gh6�D������JrrJv9}Z#�l�r�h���o�Km4���X��D]��=�\��`��^eF0����e�����DE���N�'8���������tM���&(}1UWL��gV;Kv#m�G����=�����q��}��i�,p�:��yP�4!G!X�D�������0��P��!�PZ
c��p"�%/���:� ^�tR��=n�����������<���#/
��|iK��R ~UY�'�oc���Zu��y�t���EDd���F)\sI�YFR>5U�%��S>-G��E_^��3����gN�E-�[�������K����)�:z*�M�������?��d��g����l������������H�i%�����j�
�4��/G�J`!e�� nY�H��(mY��/�W
N�|#�H���H1��] �V�[���Z���Tk��A��`&�d
^��l��t%k�WR�OAg"�u�
�6���G�uv�f�$��x�#0���h�z�!�9�8?���%KH�c��������KJN������f���1~"�SCN@�p7������aF���\�����..7G�	b�I�M������F�����N��.���t���;���t��S��O�73�6=��!��J(�g
r���(�_2o���D���XjGX�SN�0g ��o��~�T���M�t�#�6~�2r�V��k���8�����w�j�L��gw,W�IP�B�T���)�������as2���8T�e�
��l���wf��!u�a��l���U�:>��
�i3�({9`3�E������A��k(<���Z5BG��hwY������cl���J�V���g��722�b��
Rbz��wn��|/��o��w=	��q��`;y�)_#�6H&78|{v|t\Z�<������*����R��A���S��,��J����~f\!�,��9��I)���7�������@������V7�.��&���>��!�L��X����+�MS�g��)p(��Q� ��;���[���&_Z�QS.���(����i6���5�	�K�\���_(�����!S
��@���4�ly"�Lc���>]��l�w	��v���
h4j�g���Up$���$����~U�5�M\��cv�pK
~S�%��U�m�5�����<�S�o��LR�xv��N��E�L�r�:9�ss{V��[�=����w�R&��s��H���J��)�>�D������&�*�3�f�
5�=��A36U(�i+�"Sh���Y�m����U���/�in�	]c����hMy%��>��a~jM;t���o��T����HN�p��������,I*!������I�9
����+W��*kl
f�/[\��b`f�V^zQ��g2��4�~�)�1Y�y,�LsI��r�u�M��N(�M����'+*�H�N%�re�p��Ku��e��D7�@
��{��j�DAI���p����"1i>���H�_����>�!���z��!61�C�.�Q����Ez����Yn��|y��G��S��N�������I�s&U0;p�����T�99�3�w'a��Wk�=�ol�TR�����w���L������i������|�=�����"<bmc��W7v�L���i�&�/���%�SW�p��W�����;C'I{,���J�)/�J>y�����S�8�}�3��-���1��(�|us}��2��B�L�<��[=��/�|��R�'�����l�{�l����*�����N��Wo8�����V���Y���{� �G��sy�������~(��3�]��~�J.�O'���r<����\����2�`�mm������'l���%���N^L6�$(^�V/��:�yA���=��I!���X/-��G��ugh��2WA��V�����]T"����[�zXo�}CIk	>��
��^��-yJ�k����x��9x�����`���Z(�v�����C�NY������*]F�a��e����u������Q;�ncJ�0����������(mH��#��YD��(���������ZL4b�*;ah#-m
�%N�-R�7��K�4(T.:�N����,]����x�;�L���#���:�a���t*GDT�{���R$ ��9^H@Gc��|��me�	Tj�
\�|]f� ��dO��r��Xhz�U[�\��D��vh����[w��E$��#����{ )�#�]dY�4�ew7���u&m�7�2�u�^����7��Hd�$�PRE���h�bO��e���M���
�PCf#�mZ�k��t>��wY�/�q�){���/��}�f�Q��D��}�H&�I�f��$%3�h���"<S	+���wn\��2�2��8����Qq���,�e��~��I��G��Y�i�����E���#u��"�6�Q�)�Y3_V��<��.o���je3|�f4b����`�i��huUH�o�����V"��8T�<�g%rq1Yr��2�$ks���A]�o:JD�m#��	[
?=B�!���4�du�����'��?x.i���7�
�|�f�*@�OO[���0%�w]56�f]�����������Q'��Z�9|�b�,��7w�&#��+��'o�����aU�Nf�M���v��9R��.e$�m����]���nnFr>����(!3��/�1:�(���?E�`,'n��oX���)�E�������{kY_��Q��83�����:��z���A�r��\�\]�c�M��t����X&���MJ���@�~�ib !�3@;��'�Nvm����<����<&��"�IC���1�������������p�Y�J�l�]?��������-��t�����3d�"�*�����	��pn�#�#I�������U�D�+|NQw�6�����B�X�����[�X[���w6k������\�JU)�*JW�/�cE�_?���u�����W���fTz3��t>�u<F���E	;�
��o���e����J^�C�E_-�\����	��EL����Ou���\���C_����������+v\����&��%<��7_��!���@5!�OB�("l��0����n�����o��U���o�M�nx����[�nF+[���:2�m�	���a��
$�����PnNcv��L�1�NJ�;��`;���Z� ;2!���P�e�v=LJkH�`L���jO��#:���t�ZnG��3�ZQ���>(Y�1��D-Y0-O:
g�f�FGI�+M�_@BL�~�"!T��eT0h9o�`�rb�7wp���6���kSMg	*�����[V�i	d�Q���w��'f<IUI>M����������f�����l	���s)�L\�bkg�u�.u�S:����=�|7h�M�v���-y	:��%~ �&��RK��)�+��`4M�W8�����7��J��]##��j5�{�m�������@T u���3{G��S�z�c�p�!�9��������s�a8�-�tw��W(�$������3L��/;r����GN�u���-�
���B���^}a����&g/�c���(��B�0�M�{�K_�I���YH����6J�X���w��7�\��������|��&�P���k}
���q2�v\�u��c���Q�Y��������o!��_xl�����ph��O�t�e�B�mTjhY�����a�d�e�_�(�{/��������/p�E�e�����C���z��-��~�c37N�����6lS���>���3��3`�-h����c�f��r�A-V�"�E����:h���
���	%�9�s��K�}I-���k��NV�2��8	�h��0��/����+�b�����6�������E<�d��^�4O����z���L#��8�m'��U�'Fe�so
�i0���t^B����&�\TZ1	�G�o0����������0o�$����$�S�:J��-�|��(��E�3�9��b]�a�7�P�J{>�Lb��Gc�v���t���%�^�R[�.������D��D�`����0����b�rdRFD���E��Y[������ZQ��j%O����G�y�>���:S����2�i�M����xxs=::��(����vk�v&`��O�	3=@D
�a�cxfK�<�S[��,L�6��O���9�
�d��~\��"�����i�������$b������b��w�[�C����������*@.^�k��"��F)���'�G�Fkez1�&���LaY">Y��hZt�
L�B]����E���K���+)h�������70Q@����3C���&��J)����,�bK�a���nfi�`'^���\��I���T�"5S���3����
S"�Z3-��w�b`��>��|��_*���[7j*��
�LS�b4i��r�������J2�����J�5��������/�����{N���4AZ���';/b��7$!/'�,�/�n+*������xN�)��(R��j��/�v4�o�����^Ab=����M�����x{w������{���jQR-��Qj)���g4����:������G�\G��Z&+?`�z����&-\��jH!'\�a��5�8{�MX1�~63�)�8{�>%10E��
�x����wV�@��"�3R|v'��	�j�qX�5VuB�1���o�@9�2]	��	���O"��y|�����0���-sc���0���*�q��:��;�M�W*2��r�[��:�����/�����������h����y�O��qs�����S�������^���2��g|�!�C���Lu��}���&j�0;Y��1C.��H����G���:g7��zOS��Y�~��y��&���oJ�(�Ju
m��"3 $P����7!i�}�;������	��D�j��z�
Fb�����u"O���M^] K���t����$��svE	���(]�c��"��������:���_�������k������c�����u�`���|It�?�������p�)��p���-��X�;�h�d�BW�*��j;E
��P�a�I,�#��_�~�a���`�g���M4+f�����n�p�Ii@Iv����������j�*�k������)V��������O�}�6��-x(�YQG��I2Qek�
E~Q�
��j!N�����F�q��#U�����u�"���@����e�3�����(�O��(v�W��2
r��D����tA+$M�K�&�V7��s��b�N ���O����;��d�2�\���a���c��k������eM����?�GJ�&�?8[�Yr����'+w�-�������r�*>�v�y�� �����r0����!I@V����{�����%h������/7+]�w5�K|��m:%7j�	����O>�i:����gL�#�W��A�o�%|
������G�!`"��L)
/������|�
Wu����V�7���'��i�$	�K��1[���u]���2bBd'�$����DM�LR���u����j�l��e�!��OY���=�2��6�N�#�-ef����'��U-�^V������5�X�D3��v��ZKwY-��
.�f�k����%Tc)���g_�iC��;	�zBK��IN���M	a�P;�W�r&o����8�OC:���A�{@s��
����=g��x+{t�Y��F�����l�v�b�r'��3��8Y<kzTB[�`�
�Dmnl�%�a��K����dP}zN���X;JYS�)���������cp�O]�9[#��[Ed���W�f
�MV6�������;�M&b��WIJ�8SB-X��K^��&��'�d��u����*���'&#U������f*�df�:�����b��FH��?b�@@>&2���<���Z
���*��,��L94'�|�h���,p��Z��{�\����
[C�bCF��[���%�K������k���]�3�/�P�l:O�O%H0��v!���He�p0��4��"fUg�}7�D.�?G��T�� �@���l��}J�����'�y�E�Qy���+�
�v�1��I9�:��������Z�����-�;RMQ ���E������&�H��F*$���M/�����b%��3�V��*�%�/_�<1���4n�h���l���������������W��������2�xV��Z���;�`�Z(����X�I��l�s���)%T�2v�FNU��3U�?�������2W���2NF�&p8:r���A���|��E�l�
���}G�%�Y����T�?K���	<��I��>�t+ync�����z	��Q�>�$|0��Z���c����N�M�[��M�[�Y\�����F���{�au|�8\/����(�)Fc�IM��=B���x�fo��lNi{�}����x/cz�t#L"��>�����P;�����{@��u�q��4���h"}n��r��z�� ���L��a�q�!���>���gNi���sX<���w��<0���A�mU�r����!;��������d��N=��2x���������cI�����.3�qO)�
������q������������yl�wQ���/��p���bm�da��}]����+K�;��2����4�s��������'�����Nw[Gf-)F�K�<RdK��&g�y
^K��������Q�{��~��^]�����y��"SUhL�c\�<����J������l@�
*�t�b��2{Y5
������Q}	�H��cZr|�C�}�x��������TjU��ll�	,�.X�m�/�M0,�����0�#3S�B/�B�1��1WQ��t�W������c�t���������3J���P���O�[�6��N�f�c���"���=� ��?�l���e�$�U�n�WZ��ai�!1<�^`h�� ��;+����3(�i�ly�H{`
�&��>e�7���~���H��C<��=��2��S�y�:
��Ba�"9O)a��m�n��}�=9#�V�����i��}�T���ji�����iJk!2=�L���1������*+�d�!-$�)�A�W�!
c�j�0��k���TX������h�����='12p������7��>L;�g��M�	�l��������HJb�T��>�b�����J����������D[�����G����6YH���g`��%��z��cj���be��q�BY�{_�Q9^�	O�!I��J8�����0��4!C7&���u��~�&*�	�#�9�S�����05��|�Y�j���V�u9���{I����wFE��OhC&RopI��!Z�nY>^��J�QW���t�\��E0�Z�]�[io8�4��]RJ�=������JU��r����^���x�I��D��������m���$�(��Y���@erV?��1������4���ka8&1�Y
L�l{�u+���L��Y���n%Q8�^�i�N�L*[h�5/4K�6���8u�U���NB%B`I��/���l�q���p+�"�:����
�$C����1��d����az���d�mmf�^_�Az�������.�������W�3���[�L%w����$s��z�s��w���FK�������,�eg�}����6���C����?��{�=�E��]g��7^��u
I#=�;<����s[�����c>��;G�����)B���>"����(r�]Y}�6�[�XSC6��_l]��uf^�� ^��S�1'�~g(��9
,���c���O�m�}F�2������i��-������'M��]��@9�M�2��	r���������zW�\��o����iQ�lq�,��[1Id
��)��J�����CM��V���P,p"��V����s����DkQ���H=f?
�m��q��W��
�
(8���Y}���hv��i{6����������-p��N��
O6�����O��G<l*�(�Q6�&�_���ID�v�\/B
3y�<s3����7y��2,,Y���;�����[l�B���L
}_|�b���{�p.�i(��;[X<mY�e�Z���\�f���,@Zw5y�6eqXd���(5�+y�B��=��=�p����"V;��s ���a��C��m�4���0�?�������t�@���@�@���,��zhU���}�>��!oa���v��}t��#��,�H�_Ja�o��Qw�}e,�t��Y�
H�bo+`���Z��1�����x���v�6�%�"jlh����-�#5�&�(����
I���~xZ~]57��CC'�rX����:p)��Q��)�)�P�y��1�#dE�HmDE�K4�6t�%�2�8�V�n�I�� �,�&����2'�T�����/���^;��*#��
���>���Z�C��>Mb$ %���cV������Q���~2v�E��{���,��'�g���6�oS5�P'���1�n���
�pZW����K����zN�c���"��-YU��8%�f��"0����>������
TTC�gN�J��]/	b�0J�
$�'�����ia���(�������u��4��I-�9c1q����sf0)�Y0]:I�&�]����rh���a��1.ac���3�"��������F����i�e��^������OB��EN������f��*2IUc��.-eb:�~xN��i��`�U>�0������a�#���a����?h�vj���9�E*o5�~�a�P�h������:���`%����8�N�'j-]���t��Y��UXN�����	�	p��1��`����X��[smP�]W���m����Tq�6������7�2r^����7�N0O2�/�5b�_��P��_tz1Z�+Hnq����,+�w3m�0����vs�G����s
�3#�a�����s*/:��w�6y$1b(���b�[�����G�������;��U�L�$]s>�6����}G��; i�>\
zW�-�R@L�����p��J�Y���+�{\�!�G��Iu���O8e�]�f�Ynj��,��0�%����t���������M������G��x��������ddY\���%�W�)k�Y((����#��:��:�>����'��D&����O��Fr�5����%rl��/�>GU���M������
7���r�s�������������!d����	gE^I���6�Tk�}���4�4�[n�0�P�|L�Y-%se��&F?����V#����n��`�N>W�U'����~
X'�s���xg^�Y��M�G{����D��\"N"���Gx7�H����=�L�����::����}��CB�W�Q����
n��L|9V����s���v0�V��*��������T���Q�"���D���O�1���A��
����8�c��@����ny�6;.e����(F�Gr����i>h�A�I%�������f(`��� �F?FO�:�v��N�[h�0Rr�@C�+��P�?�Q���0���?^����/��B�+�(/�XT�,��*'������	��<f��H�����%y��*�L-��p�����:b<��/K|l����c����$n�E�['a'}E�����
��������5f��a�j%��*gJe�C�fu{ -�������<R+�qR���()�.��H��������b����h�o���=:o�l%*\*��*�GM'1v*�����l{��]Fsg����1������W��<��e�3/�J�#/mt)�]���YL����1��#��������]r�E���Z���F��4�g-� �Z�1�q�z(c���cY\��gw�=����ob��#?&.��G���"�h"8w����h�3%�"�1�t�a�s�I�����B���dDn�XA+{Q����SNG`�q?`��V�Q�(B����AI��f�ut�l��Pu����kFE^���8�w��dPXr������Kw$gz|����2),1E�0�3���I�����<����O���0n�K����k��o�isT�6<V�K��g>����T�K1���|s�"8�M��vQ��z�(-<��'�	�$�R��x`��r:*.}I��F�/x�WJq�� [�p<z2'nA9�9�T(����
y����z��qs����';3qL�pY�z�(%�"�GRN�
��[5�K!$7�*;����V��ox���+Z�����wJ=�)8H����x���}��-�x���-��D�v��N���n��#���Y$�N�Gs�Z
;�=��'������C��5�,$�8�����I�R��I�6��1kt��4�^�����]���Mg�N�����2�%N�^���0B�(r1F�����Y��WY�x��N����O��K`����O'?2mK������Y��
�-}����	��I
�4�L�M����7���1rQ*��qq��R�8}No&Y�oQZ�m,N�3�|wP����
Qrbj�(9��%��dS	�G��'8�5^�)�}4Gb���M��{��~�~�&������Q�u�u2����yS���y�����y�y��yj���R�3%U1��
��	N4��a@�A$���:g�����-_R��J��N� ���/~��T\�LKo&��o�3��X�L����AU�L��=���,�<��6�|��kE�^p/�XT�� ��)�va�w?�V>��r��}������|N2HE�}��i97&9��)��\G�GY!����v�<&�=�=��;����w%L>�D����} :?�0��^��ua�M8}��193c�<�:r0_8�*�n�f!i��m�z����A�
�-��*�2�YZ�<2~0���l��X'��C����Z 3=���O8r0gZ�Q�4���~��jt�@������jP�\*��
1�R4Tj�����Q$T*�����fm�����C��N-9M����M%l�%�P���:�7[R�4.�i����b���Q"SC�^��w��'nP<�L�S�<����9��3w9d�!;6h+a�4�ns%��$G�,�#}�jr�-%�k�*�Xv��\)�����J.�;���.�w�������A`Q0Li���/	��Y�O���l��;F�)�:�������������R�� ���-_�+*��yZ�f��b�������xk
�o���.��3a�+~�6�?�����
�	�@g]�P�*#6��B����L�n��A��&��;HVu���[z@��X�����"��+�93�R��\�����S���Vv7�����Ks����H�Q(�����\$77���2#�c�*y�I����"A����,%��a�#����	�����h�r�P�l6*������Rf���I��&������cp�@�NZ�b��woQ�=(��,�B�GC�*��c������H�P
L��S��f�/�47�������rP~L��s)�h�������\=�I�����.+�R�'�F�3*]
���X?>:l����o��y~�m����%��e���M�����x!W�s�:l?_Z������\����0k���uc��p,}����?I��Iv"2{�KnmY�hy�~�]c�3�W�� '��������g��p�`i]���D����u�a����<Ti���$�@�(�1����#~�-�K�N8�)_;T��m�'��<�}������yC�39�*.��6����u{�/���.��@p^�������`���\w�2�"�R7�A
U ���f�
s����h|��/�3T�u-]�gs�	�Z���D���$���+�]��Fs8|�:���5������-����'$d!Z���	�;���so��O=�!���&���%����e�,&��k���+���8����\:��cw����U�!�9�P`x���8������������%(,Yec��
,]�%�T�����?�o���-��^�k�P�T,�FZ|I�%H	�h({v0Ifhd�3�d������H�����g���W�9�]|���pr����^�4���<��)��W�a)�&Ig&�o���$`{s�R�xo�T�[��+���'N����k�8���T�3������l	�'1�]��k���mq��}�
�f������0x����������s�q�y��g������G�,9�����R�_��|w�F�����/��N_��q�����I����H�**�
�d5�������!G���5y���t���r��NRb6?qn��[M�8_��������c�n�:�}�%�T�6�(\������e"�B��{��+p�M��!V���HG�A��)��2�S`���S�T�a��lql��zK���9"�?X
���x���M��K�*�������+�q�j:V��hQ�I�h��8�e��>@d�k�_�R�l��d�3)%���I���V��@[jwpk���^e&��b�����9o{�8�����iv��N��{YSEi�*���P����% �#&��'6�S;E��s�W,�������3Dr]��0L�o���r���W��61pMB�D��v)��*�R2zIJ�\��7���WL����H�l	&0���l�#Pw�+����,-J K��o����Ck��GS�cy����	��"x�����WoM[����H<gE��5"��:�����\t�R�I+a�#���bR����L���@��Ww?�i��8>\9�C���B����j�Tc�1��4'��:��u�%u�����8F*��K:�m��k��Be���k����*�����h���a&\���P-����"M��Y����OHn�] t��7����[SQ���l�<�D/��'"�Zr7!��D��d�:,���%w�Qy�w��NDkws�����-��G�(glH@i5������y4���^ITi
l���$+��p���\��Vq8����
 )I@�o��0���)�S�B��Q�7�R1A���h�-��pIj�a�en������dQJ��b����/������PA2���l�p�W��w�"���C#���k�o0}������3B������\����k��	W�U�G�/�-�[�|�RH�
(�sd���0D5�R������I��	��E�6 �Bi�e�Q�<Vk\��d(z$fb)��e�p-���������~y�����%ey�u�G/x��Ug��KUh�2+�.)��:4�����h��}�b�����+�i�hY`���^��~�c��,Ezn?Rfig�-��!1�'�2|�}��.|�G�X<�6���������c��n���#�;�(@��&��I��*��|K����h���)��<a�oow�R�
��[�~=�IF
(��7�i������Y `��:��J{d��x�5G���8X��8���\4�Sm�S�
c��� �h3������>�G�R��S�3J�%����8
n���eX"���i����_GJa���L8���z�������W���(;��e��9fut|ef�U�YF�.�����L3C���w���p�����=���H���&��
\Am�NanI�b2��>��4B������""�a�#�����h���
!��H{|���SH����mO�mUT#���5+���[��z����p���F�e�=���N	�Z��^�����&~yxvV�
��R<3�#2���������C�����J���Bf���/�����P&�����ic�/��q5�/Zg��8U�E^K���������
��@1Qq�f
�����6v6���Lf��RxG%C>r���|���_)n.�������3����D��!���pQ�����F\�y�%��DV�9a���q�WTHd��Qj�q���C�8�� c��,�Z�U�����z��0�^�O�pzD�x0�I;Ql:��,9����4��dKfB�$eK�����[7�f?�~���6�ph��F7)��4��EvU�B�P(
5�m�
_)09"K��N���������@�`�h'V�*�;S~�7�yTM����\\��&j������!V�����`<f6b�����e��Ou������I����$|L���	���}\mc�����)�b/�P+�2j>������By����H���G��06�*�p*����x��`�W�l��'�S&�b�����F,Z;�}~�1��Y���wp��G��WF�dUE�����o����jnF�����9_���������V���V�`��
�����{��A�&'����dr�����k0�/���	y����)�J�D�sL')w��(2oD��m�+r3=b�xrGq������"�8
����.�\��C9��g�!�GoCa��g�����::����v��eZ+mj���%���i~�������Ca1[L�
H�@�`S|t�kIIQ/��i��������17}�Qy�����p�e��K�i[ �!zp)�3��]�F#i�{Mp��M��V����Bc��*�A��e����#��M;�Wq��c�ZS]?�5��/�Q����m��Z����cWJ&����b�D�
��w&���c�
�ya{��
7��V��P�NR	N���Cdh��vW������VXZ�5�y[���q^%�Q�'����:�EiWj"���<�Qe^�g���:�p}I��c��x0$$�����m��NZ����Q�@������9*�t�L*f����|��M�E���uK�~a��^)����N�����gM?$8���\i��f2�A�n�88:�����c�1~����?O������
��=��C�@*��.�d ,I������F;C;@y�7Y���
9��3�(����'Z����\�X"���;��f]@��;������������^�T��u���~W1C"���)�`��7?u~W&z��t�����V�D����;�2n77qnY���[��b��'q���M�e��	f�x��w��O_n���|���k$�0�[������Or��
�/7Mi����k���ZS	8�5e���j~���g���h��m�4�b5�R"\eiIq�k�=2���B��h_������7R	�/�����H0�a�M���k2��T���jwcn/�9�]#=������L�5�ZG�!,N�������X��5>J7�l�f�0��u{����>�@Z��D>SlB>`����"c�:������RY6Jf�����,K&.�I��\��}�.�b�=��������u�Ps\��&�;�
��z�����oH��b!-��6�8n���g��u�l��V��2�J�"'X3�&�y1��D�YT�/��d6�S$c�?ad1|bA���djc�����r�2��=��^t��T�-_��@a�
S�����<��%QY�0L�e�z�w1��nUB�G����\\��w�3P5z` ������f��GE��{J����<e�!J�}�CM�'��I��Q��
>��TU���x<a�e

0K�Q�!o���"d~�P�$T��W�@u�*gG�3�0���e��5gW���%��G'p�����-��"-���6��O���._�	������5������V3�u��Y��������a�����T]J	�N�cmW
{�;jO���<
�k��:Q�(��`���p�N�� �M-�e��"��.�(o��'9�b����p�r
�YN�G��Q���ULdE����N�M��3�e��6�\����bq�<���d����0\!^t�NfSGe�����A0/-��p)"r�b�_Jv����)��q|Q��lh���=���j!�\`��We��N��bT5'6@�6W1��o6W�c-�i� �?���t�����z��h�~�} l����X`"ND�?�C�9��9r��/z���Q��	B�[LZ������<DT��^rXA`5"�&
�A�.���X}$����DBIYgi��f�q� 9��`>r�N�.;�!"(������T���"���^�L8����x,�z6�I��rCc��,��p��l�k��������=Hz���^R2����}�����!Ey����J2"�����io|qI�������d�n����G���<�R����=&�F,b6-�e��(|������w�N����ncv����2W�m��k{l��z�h���mO>���9[,^'n|�;�	[2q��Q�d��rE�����}�7���u������nb�����`�A,����>n�^6���>�6��J�<�~���H����Cu{Luv<56�bYMF!���������������:,�&�a7(n�c��+<\���[�<�N�R1��j��#����\�w���
g�m�p����d�b�S+&B��'���#��l�*6���������������:e�,S��X���@�M���%�""}�t�)g�'�Q�Wocc��y�a���su�P'�Aa&Y����E]�<�bi���DB�tJ�L����������_�e %��������BjQ������e�$���l�o�����$G]�Sx�����e�q1v�d�������*B�(�i5�%��C�����L�����rD�h���e�l��(���`�g�����q?km�*��q�X\(�JI:
	"S���W��Y��u���r,�������,��9u�<s��^��`��
�[�w�K���A���r7��<�U��t�����l���os�����u��/N�Qnc�#i�|�E0M�����P����l�&i�;��gg��M����<g)js�����I0�c��B�e���Qd�N��X���Bc��`3vO^Y����"�K����{"F���S���lV��H�	�����Av���������^S~����5���U��r�_9�;G9��r�4��A�K�a��~$"���?[��/��U���L�������@M;�1V�H��!~��O�o�^�$^C��V��������*�L�?8���i���������������Z�%�~�G8*)�Z�� ������E���4�2QmQz��Ip��cja"�,�N,�^_F��Q2t9-}9�a��;?��)N�t���\�L����8�$-�f;e�M%�Y�;��Fo���'�Bn�@�%�2����Vg�y��uH5��������H�*�R���!��t�� ��F�������&�:FS~�����&:��e����3��Nt���[�0��N�m+���mD����X���cIa����>��2*.�4�����G��x[b	�1�.:<��������F���*w�`��w(e�=De}�*|�v��V<����X<F����D40/��.��C��\�]�{_�y)��^;�6d��w�q�[�k>��Z�>�y�9uI�����
��E��<7�I�fOQ�����[����H.R�%B�B��;�77$��!y�M�L`��&�J(6lPf��J=��n�xi+A����SI����|4s#�B�|����'R�S��)��o�P�E�S�N�dn�zD4�����pM�kDG��~Lk:9�� Sr�(�oU�D��B�U�l�3����b!���Z�3E����Y@G;����������NV�Ht @g�x����\��a�j7�jx|l����Id�\��������z��A�X��Z�����������9��LD�is��r�r����~���J\��k�8%�T$K(���K��PQH����[h?~���J�Xl�����2�+�z�����%p�h�W���cj�j�b�����{�y���6lE��n������]�R�s�+E8�2���-���?�[O9�&K1*X#j%��w���@�A5���rt)��]KE0g�ll���Q:������������l�?bW5I����m�t]�tY5�\WdV�������zk(� S�.�U�]uY��L"��ZQ���^���^,�������Nzd�43�&d��_8���X�����PTu�����y�h�:;��9mc*��+\��:� �^.�"Z:f�+�(r���������$���F��|��v���F���h�])~.��&F�cq��0����64��>&��W�*P��s��eI��H~Z^;6Qw���0%�N	�<Skw*,�Yj��Y�rq��P5N.�~����_P^7�_X�Q_ZQ�nf9��1e/.;r�9��c�����:�r�9_�Ac������\��:�l���1&	����,�Q=H�3���nJm�cw�AV ���L,B��:�?J��N���'S�},�-�"�k��W�H�'��5�Zf������o��J�72�h{�Uy(:6���*��y�7�f�i������H��(�#F������++�������)H�q��sDL��P,'"h$64W���������GA��/�e3�� �	;5Jz���=/�����B[{�����Xd+����+2�:�?U��]����Pk�n��K�>���0��d��zHW���iYM���������F�kgU��������[�5%W���0��c@��������h����Wh���v/���p%8ew
��x��1D�O���	�T�JL��_���=X����(�jMO����I�jSf�P�������\�?��"�j�������J���
�A�q.,'��\����*���D�32���:2����S.�����_k����0�����pK~3�C#�cc�B��a��&�^�&�^[k�c��j����X�%�?�
,1yH��
�Q�S[�Z/��pA�N�C%���1�����E�j�1J��g�k���Hb���B��x!�j'Q�GD3��^U�[J�(RJ��0}	S	�b��?�:��h���m�����h:	��X��m�)�����(��^�?C��afVTn<����x�S�<�KKEh�1OX��V7jm�^����:����Ky��t��0�[�!��	����S��N-���r:��$�Zl���RI;����$x��,y��?�U�C���a�`�"�x�#6��$u�Xdk��Uw��.gj�(�`z����R��C�N�
�1�u\pN'#�]����Q���z�17�[)=w�V�	���`��6�V�������p�S�uL1S��u<��t���K�$�0��$������O[���5���@8HZ/��%���LzU���
D<�$!�i�z�}�)�?�l>��:�1������pt��*�����:���Q��������~m)�W�L���Y�+����i)�"�2�&0j=�D�c�ev�Xt�Z����j5��&i��Ue.Q��K$���o�����4�c����x0L$��!����kq�����.�j��g&r��xU�$U��q��|�����|��oy	��c����KS9<��y|5#����(Y������T<<�~��R�2�Zx�����J�&x�m�I������$�T�����y#��]%VPM
��P����:]W9]W���*&��O��9�k�)��{��Z�r,F���2�V��c��9��6�r�Ar����M������s��j�C,b3Tf9|������WG��X��(��<�0v�9J
���x������XjaE�s��-�m���Y������������6�~�V����9�Ya�b���Fm��6Z�
�o�,��e��C*��#-p����Fa���yZ �������c%���C��%�m?����l�����P���@ ��^�����Wa���h���tO|�B����P�8L���U"U#��.�;�M������p]�����kk5���i�=WW�+����<5��(������2�T}_:b�s	R�BY��.X|��z<��=N/�?C?�$�8�_D��-q�{�����M�2y�W�����E��N2��-�g�Tn4�-A|��*�JD��q����`0q��Vc����41�7����jCo"�BA�3|Q{�Xi��9]L��a��d��U���m$�|���^Q#���1�
Hr>����`Km��;����E�����ew�R_�#/^X=�Exog7�e��!}��BL�(��?CM���������)�a?�z-&Sjb\����z��S��v�0�����E��*��#M��u�i���������EIG�0Q';JWI��i/�a�LT�3d�����^t�B�
,�k<�����~��k���`�����w�-6���Lq�P��eL��Q�4�j��v^<1���@Ge	��+jD+����|�e���<{Q�^hB_�������~6[�x2(v�+�q��P!�l�ar
�=a����lK�|�.������-i#:JB�'3�.Po|��A�Z����A��ET�!3f�?Q���B(3���g@�}�oV�j������
�7�At��#��dU�&n@Sk��tvp�/z%t�%qG^r�1*
��/.3q�03���"5�I2���Q-a��y`���o�E!���}p3�K��$���+�Q(W�r����s�!`��"����n�Zp����l��Urt�N�A%K<���a��gu����/�������l+��2����9e$�a��p����'�E�iNU9�b�T��gn�>j�N���<�G�Aj(;Af)��}K��\[5��
���_��,����#�)�0B4������!��xA��O"������FR	�I�Ma#bKuS�z����Q�
�I^��F������M�T��W4��H%N%�����xt�F�
��p�M<��d�)3�z��`\�llwT��?��ny~��p>���ml�%����e��IA�u1�7�Bs0�s��1%uc0u� �]�=����;�9�����0�_;�;��V��f@����<L�[KCWf9�2��\,�V��T[�X����������D�%�`�H�'dQ���G��Su�23V�Z� ���~*+�q���rZ�5��e4��v���$�@0U�r~��a�z�B�v�95�D��x'n��s-W7}��v~
{,l�������9��k�bH�g8%qg�6��l;��9*��iV_c/Rb�/Khg0_I������Q3iO`��y�2��gV1J%�&qL=����nL�d��_�4�"L����7U����/��=�V
���bd����%����B���`^��sg��
�	��B��4Y�������7<#ot2��u�\^$�d��9��!vwf��K����D;�@]��X�D��J��L��t��hYc�Bm���.�����1��������������{v��c�v�����`����~����.�7�Q��tQ�F$�N���!�v�C���<?����)YX5�,�Q3�2�XN��������;�����I�_k��'����,'�x��0�A���g�
��1 x���+H2���S���d��cX���_8o���*/9J�S<��u��(� *���d���hUm����I���Wr��R��eH����
g����YY��Vm���eq�hM���y)�_iM��o��w��h����1
��hp�$iRgOf�i���/x�:���Bt�)��}%�?��B�_>�;0!�A;�;��S����t����
B����J��t���T��>U
����
���������)
P�L5P���'���t5ew,��u����H�������+x��`��������r�����<�k�����a�����{�����qJ].�g;��I!��+$���Ar�������T\����ha��l�"�*�{/�6Km��Q�%�����~x&v�b�yf�O�T1�����aP���F���7��%�O���F��h��Y� ��c	�#`��.I��K�W$^�p�4����_��D�;�P�Q6F$�O)K��VNO�o/)���=9�g��gA/�ry>��py�����TAfN�18y����\2�
F$��+\�x<����SQK��kCc��p�+$���TbD�9�V�/��sU�H�v�x�5��}
kN�b�
	c��N����^v���S7UY8.dtOD�F�EV����1JwE������yU��dW�$�K����Bj���~�:�X�	y����!�It��#��+�W��h�(�*P���������/�N�;G���{��G����H�3�p���k��{��;�&��'�u�9+!0L*,��m���L1;P���qR�FoV�[C|���ED~�UQ��KU�d>��z����;Wx��l���g����\�U�Tc�|*�����b)�%^'����<�X<7�y=��(^����N?%"�/���?�>W����g��$uuF���Fb��E<����P��[<���$B�/Z�HIJ�Q���S����������VP���9��L���U9�v�s,���O~�9�]xL����(x��L�����-UK�5���;G?�_�_����0�gtN�n�RmD�HI��Q0c�C���~G1���:K�;Y*�	B|�^[��>�H��R�6!�s�u�Q'�E�=�=����4�m���o��s�7�<#f�b|��qX�"S����g���R���$��k�I�	fwt�&��J@��������n����i���|�R9���������y\����F�x��2��X� B���g������_�t����2���F�M;?���57���Y�e�M�huZP�<y��Q4�������	7��s�H�.���Rm#���/;;���4�
}'��������0,�����b���i�����fc>4.h^��o�����8pk���M���UG���"|������������r����O��~G��'�;���'���~|~�"��A���{�Az�y��w�M���]�M3����� �~������Vz�����F_���?t�����{��VD[r*�DmiF/���YO�p+����fJ[n��Z��SI>S�>���F��cR�O�C�?��>�����������QR8L�k�OU+(�_cH��t.�<Y(G�'5�Qr����r3�+�G]�$d�Q!����'�*4&8g�v��*�s��y]�CB������N)��8)���M�^,����B��A�]$]r��&6�M*�#����F�d��*�lV�`2�#9�k�M�n^l�xvm'����xG�1�v1��'�>���T�MGv���%WV���j
���}����z�|0#������������`8}�g�D���Ip��4��{�2����zs��hu���k6����z���j����S70��Q8�pC!��
R������ <W%(��l��t�x��8�{�5����o�>]Z:�?}�7�st��C����=��;����{?����G�u~�9�������@��z@t0;�;{G�������
d�/�r���~���J��+���*�%��v+����m T�����:��9�����j��&����.B��/}3���O�`�t|���e������K��	��O��9��P�����������]������M�������fv�rD I��t<9�����b�K�j��l���O����*�����y�J�)�����R�<X�Z��o0���A.���N�P��w���~P���R����������k{����B�*����;�ETY�D�qI+��0��E���T�]	�a�>;�������l�0�d���IY�������8����sz�����bw�
�6���-�jo�6H���]Hx"�>����PQ�aGR��T@�
�d;y�G�*�$L���=Oy�Y��@{B�	�}�i��2�5�����~��<6�Q��:�u����9"�;���0{�c���������Fc��Zm��r�������{�P�����������7����t�}D��{�oK���)���H|��P[��6���W�g;t����!)}�����������z��������U�>�?�������29����'���w%71��������#5��!&��.�,9��ep'7�������������7"Xk�U����;�Qi�]R��3���	�&�;��F���}z^�C�x��]>�r�F���O�J�!j���������p��O�7��yJe�C�'h1�*}5�w������ZW�O��@����� �L=(����s�5���3�����w�wS�\��A@�Do��=�����������������������:~r����������v��u\?�?:yP�����&�"�pv�hIiL�qR����<e���-t�2K'����*@��<����O	BAP����*M��j�y�`����u��x�B����	���J�a2��������&��6W4������+T�����	(^
'�i���r��
}}R��0}��x���$�6�>9)���7}�����l�����&�n���Vat�
�O���p�������o?4kFr��UG���}����a��|y�o������8�v�ZI�����V�3H�)[@��)*����N�9��P}!)B��O�����_6��]��4���l�������J�������,���|�����}��
�����| TZ@�YY>�.W��"�Y���'���s�gv�g�g��9����x�^���O,�'��9����x�^�~g���]zy��^�r��`��^?�*L����
�e��Wz�����GCZN���a�#Y��L�O����&2�Q�H�B���*���B���+�k��%�T�
�o� F����5������tV���K>� ��d���]����q�9�]9v�����Y�qX�T��tj�D�RD�����Fd����$���m��t�f�
�JU6�7�8b}�y�RI6�u��Q~(�LP��tF�3��tL��R�}T���n�"�d�E��L_Y�d(��w�*H�_^�Lo.��!
�8���#�	��\���'��Ll��^X&����]Yr�y��!Y�F�+;�Q�,;E8{Z"�����7E��X2#�����
q����	]c��i�E��1j5�zB�6)�P��Xh�?�tN�G����5��U@�k ��@����G��_KF���MV������{�i�Jos�������I'���R��b�����������Y*��T�'D >Yp���a�K�����K�f�&P�%����K����G��Y�Q�"�E�,�*>����H��U��C������.����{t����J�M��;����0f��F��%�
�Ng;63�^��&o�RbN0H�b��u*�`�z1���v�n���V*E�@��n�e�^U�+9Q��4��2SU���MzbV�������t\F�"�����v<����J
v��������'Z=�etn_)2�w���!�$�yhxm	v|kKK���t�;���w���N����n6�Z����h��&��v������F�|�����1!zB=g���oY(lU�,#���,�EW#�J/������V����rT��(����SP!�(��N�Bh�����v`�+n��x���y'��.�!�:j(��oqciK7v �@�	��FB���C'�E�m��R���
�����&��F%?���������o���	$�X�]���C^d�Hk��A��T9m=�48�c{P�>�{i��,]b!Q��S����/��e�'Z�w�z�[���
l"�W���2Os��e�mr5�W�g��R��
�V��nm6�38������BI�\S�Aw��6�;���M�c�f<��g�r�G0lO�i�������\��x�+��)h-�.���~�ty��x��0�����$�/�w�J�������S�S��H-��:������8c��:�b��Y��\\=��AU��L�����`�g8)Ofa��2��?��BU��
qv�T��h}��&3��5�`z�C��	;�5"��{��%�������y�����$<�R��Jej�"�����s}9Q�wOY�<cw��3&W��p���hT`���i4N�`��y',�
6q�����k�&������y6'=J����%��Q����%���3Z4�	����^~��9x�9���jw��������#��?�r;/�ri��G@M����a&�&��LyE�#��{��G��oC�9�]����V8���
u������fx�����*�m������D���T�����,�I�����������E���Mbx"�-��c�X����f�)�/2^@��K82�k��n�M�������S���Z/��=��eJ�����T'B�|�<����l�.��s��#OsMD�	�����3�.+@0]���@^����I�,.Q�=-������Bl>�����eb�����Iw0�+��I��6���[a��lSx��F���}!�/��N�w^l��=R�kf���["��Y���O�O-;<�"ShC�a����
�'�Z@�
!�3�!�B���g*��x��#��(��'�����(���St�Wh��B�G���
�N=�6�a����������%�5�D��b�BK��@�u$	���^�/�-BE0O�7�|�P��+j��L��FY�G!��j��%x�nE����4��X|�'1�r��=�������8�����H�'rD	�L~�.�[�'��R���	�R��O���KI�#^��D�/��6���DR7�����M��x�A�������/��������t�Tt���G�3�����e0���L*��*y#Y�=��f1��%*s��d;�Lf����
��cv��{������ZU��Q�8��C�c�*<]�}���_v��rf��e*����!%�}�g�9��8����Iu��6�Q��%p���`�\�X���XEW\p�*������5���+p��N��
a��G���:q<{A�K�y4L����]�@��fb�)��8;"�m��6Z������Vr���J�k��pt�!�Z`�S�m�<��R{^A��7�3:����B)�����9K'�����9���>��b�a6bMR�<TgF�#�/��&�$
���E��l8��@V���":Q�8	e����kYd�sw����jE�rg;� ��C�CK&�e��kB�<'+�16��'���b�a���]�l����|B���U������c��TQ��qL<"�3��;*#�D%�9IU`���LY"�,�[����53��J�4^x0~��|��0�2�j-��I9������A����G>IS��*if~�l�������Q�n���7�����r;?_��a��h�Y8�E�l��M��A�c��O'�&\������`�un1�Y,M����W�V~(��Q��\���Hqa�C��ql�
���=f5#�|�Q�����Bx�K#�����d��
�t!b
��P�^bE����Z��B��\�,�����B����e,��vx%�We���l��/����3&�����@�� 9`�
6�����������n�M��
�t�H�:����]6��ZT�Ny��^���d�|� m��W�e�
��i�}�����@j�����C�RP��?���mq��������$�hm�B-����h[�������(��R�����S"+)�a�C0h�P�na�\�9�^�"�e�Poc�����v���#�b����lS��kF!F�,��I�2���0�P+�EJ���d>�,LZ�t\�����]��z�������Q���������%�<X�j)u���� ��,��R[��4U�d��"T�fXF���K�B�Y-�����x�����NEh�b.�ah/����\T���?��>ye��o��x4�!tqB��^/����TckP���.N���4%�������~m}M�Dc*�L��_�i��9�x��<����\��W����B����)F�����\LT�����|V����X����K���n��^n����}��cy'������x�O�AV�1���.0fJ}[#Z���>��b��������i8��9:�k�c+�PM�v+�MYEi;����_���ag���M{��t���N�~�K/�Vi�6�����?W�M�Z�s=�CMZ�S��C��TfD��0!�8O��3�bO��������Jid�F�+jYG&�ja@��.�9c_�b�z)���������:<�x��'��J]��o���n���W7}���;�qZn�%�z$.��p5�"��(�I�^&�XVnF��o)�"�Fa�f�������U��6Z5oS�z�o�>��3`��@�1^M��Y�7�P&��s��F��������px�X&��x����5:���a��>7j����+e�
���l����
<d��+J?&����yD_Y-�%�3�1p{��{�]�( :o��=Z�����w������q5��_�4��y�[a��\�����K�����M�0	�t-1�^A ��7&�A5�)��8B0���L
/B6�A0T{XY��Xb�����t������D7��������	h�
���!m��M�%�)$�@��v���A��_G
[h1f����4���V]%�?g�\�s0b�r6�w��f=.�AC�hIyYb*N�h��;0TB��a�sv��L�d�H�W�f%(��M*v�����y�j*_A�(D��6�b��0	�^"&J�K�0�����0G�J�F��%E�:����A���w�p���m�MY����/��9F �W����5��TVu��b*��=7��J+r��$:_��
�c��]���z��$���Z#n��s]�k�2��5��n��2GR��!�"~B�1r}�(��4^P+n�'Z��	:IGp�/�|���t�5�}*������g���pV�K��JY�xh��lOp��`6[��.gU����B�y�&d�^{��m�zk5i���	�;���7u��I:B�D����E�`�Y�*�������i�>U���x������c�������!:���%����EC�7�L���x8��Wk^��^���y�n+~�b����L����"��j�cf-9<.��A�eW�>�5D��������})��3�=���)���6o��dog�0	���(��d���6��W�:^t!�����6����4�d����hO3,q7"����G3�U������K`gz��/l{M��������@?��|��hg��X8���lT�T�~��{������A���a�H���^6�[{�n�5��h���_Y@�W�?���h���)����c=�=�m�
(~�!����T������@-%S1d�:)�9�x9��q0nC��#a�e���!(�L`2�b�k>?�[\dn��2nV$�VSb6��$�b0��~_E���f���D^���5?)��#=��l�1bsm�]�#�=���V��Yn�����M4;���������"����T�5��$v�k��Z���n�����Z�Po%����\	�y��Q�8
���������jlh|���H�3cKbfsPZa�Fz��j��3�P��
'��4A�I�������#kKs���1x���2�L{4�r6.I���lK<�9T��%N�u�����l�Nxr�+��[��3���?��D�n��Hp���x�f�p|�kH!�k�x���b������h���V��F��D��L@Q������
.�i�*��}v����\"�e��)Y��F�d'\�~M�F��S�p�N�+F�0^�?T������c�@�5�SH������
(�T�����q���7KaJT �7J��X��d���daP������e];��Nl����n�u�HQ>��<���nA�.J��Y���!K��BaO����a������K�m4��!{('�{/�]`�)�.�{���Z0�	�!��FXXaL���!
�*��x���g�z����hx��f�����58�
^+��#����*d���*xB��f��&��?s9�g��������m��x���+~�}�HV�F]�q�t�����M���5���b�`6�����H>�������������io��I�k���2q�Z����)��:6���a��j����N��an����TS�.����j)�'N��r2��9Q����0X�n6g-���>M��:�d)<C��te����6-"{#i$����M3X��={7�����������$V+,����A[b�%&n�fk5!n���
0�C�
Y��H��]���Us�c$��Y4����������r[WG����j������Mcu�X����x$F����ad���%�\���O��h�uqq�V���C�������	�[���5����HC��
�n��8f0e;S�����W7��Y���������������������i�?I������
'-d4�M��<�#Npe�Zg_{3e��V8.#��9����oV��M@����{�;r��~6u��{5�ECH.!"9o'�q���X�-��������^c����MT.v�3�@��*L*��t�I�T\��,WW�%�(��?�`8�
|��������m�rP{wkV���%�o6�-����w&��R�?��.B-�{V2�\�"���)�*���I���B��\[��+[�B�����:�j��fI������c/�K������0�]�����w}����������6eY�����m�IR���{b&���](%d�S�X	�:c��2��V>zk��/���{�j������$��V�Y Zp@B���.�pj������HR���	��p�K�~	4I|��4�� �����5g��A���!�0m���
Z�'����mbP�����i�sr�t�HT'}2�"K#������iJh������sE���o��f/���G�
"�el������L���Pl��c�(w	!�\wg	��J�M��D���A���h�[z��Gc$(���~q.%�su��(K���7�����f���k�Y���6K��8�"���R��SU�9k��59�6�k��mp���n�L��3D���d��
�R�@����E�e;h���4��0����hL��+M�MIYn�9i��xi���i�*a��	���b�\���pfyj�S�sWM��|5Vq�cg�����^�|r�7�6��tp�x�C�[����5"�t��M��4�d&EF�5��^����R\]1�[�Kc��L�n0��?W�������v�YE�&������>~r'Ac%� c0/8_��Gsu��0
�s�LC��06���f�fF�Od��(��*|�z�B>C!<���63X�^�q�l�_s��J���f+�z��f��E��xdU
�^��GI
V��o��a��%�!zy�5�2����d�]���V7�%NV�a3���"m��w{�S�z�����%"��PV�%s{����`%�:��Y��Dz�.*J���j����W�t%�����v,�|A��I�m�t�(����{F����^��F�b]�[���U�M<���,m���2E����
	����`u�k����O�-���6b��)f�
�l)�fh=<:�3��-��)�b�o6���d�i^�o1�_�6E�_U7?|���h0�C���9�������[���e���
��a����N�ic�SE�)�>�C_YN�0�����#�hn�e���{�t�����!i��irv���%jn]�Et�&[���Xec�l��z��V<�-}"�y��\�@���(����N#C��)G����wEme�9#oc'f%�������a�o4�����u��sL@��sL�`U�����u������I�L��p�z!W�}�����0�f7�`��h��yg�
^<=��RV.g���AxvH�����7��*c�Y2�����?=�SR�\��p:&@:���RFR*��Uw8�(F��ze����5�q�+���p`�m0%]H����b��z4|�����3��.d�/��Ng����;{��=��5������v�����]L�z��K'zWe� GA��W5��L���jn[�d��\�o���������gp�a�`g{w��;l������V�j��j���kX���+��T9>�TmK�K�������}LH��
~�3C�[�^�7�L�[/!��dp�{�QWac��@(��������~�c������W��@��j�p�2��x�9(?�&�O�����1��Gu�,F0������%t�|C,�`
�f�o�X�w�0t��H��.�4�Y�p�Uag��VN����e9khS��XQL������A
��F���@�I6�aJ+��T\Oy3a���q�jm� �*���Z���jUq���?�1T�
e76�+�	���hH��'��th�xI�
���y��\W�?Y?�����?����6��������������O�� 
Eed/�u$5
��y��:��)js[|+k��f��P��m��4%�MUl8QS��
�Q����/0G�_�������K�#�\o|q9�f��K2W6�
�1�����}���w�1���!+<Uc0	{��
H1$�KJ2`�NG��l<�����'TT��L�o4W!)	}BU8�� ���i�_�R����L�Q�`;jX�� �����L$�
��/&,�7����1�����0<
���p8�o��_H]c�����w��U7�5�,\��J�)���^c���)^2��)��E�-����Z)�����4���r�GY��	T����)5��`"�m<rv�s����s�
�	�����jV�0_]BB;^������W�� ��
���W��E����hip��6����h���t����6�����[�5~7\��9��F���K���r��#��w��+F^
!��%�9������Q�	��Q���������t��
���	�<	F�8E�k��i
�g�4������;����F��R�����6���`XZ�
$Y���g.���S[Oxu�����r�u]�`OR�x�ev������F�,��U?e������d�W��XmR�?�&����*���6*)���� �k�o��Gp��hF�����~	zWW�zB��������>��jf�j�.��c�����'I��A
*w�`�QY���k�x������n����8kLq���B�b���6^��?�Q
mwk=�F�r����hz���l<��Q�#N��Fovg�C�l"P�e��3�L�_���:�F
���?u0����2������������~u���V�k��f����6��Q�7QM����;�|�S����5(;8���}:������,z�3���
��)���Uw�/1AGOT+fZ�2�m�pH^��
,�;��;��=<�>������C��C:ZX���:doo4Y"<{c�����3��5����>{����r9��G����E���mx�38���:�bE�'�f����P�{���*A[FO�������������D{a���\��
�_��_��> ��eS{w(�8c@a~��Q���V��4��Y��
����6��B8��k-e���=���h28?�& 
���i0�u���P�S���8X�5�������9e}�r��g�D����"	�a5���O����p��	�E��pXK
���(tm�E����><e@N_���<���w�0��Z���F����X1 ��R.<�R�
�c���R���#��������,�N6
���H���@����������=����o��x�}�'��8��eC������_��lP{��3/J��?8#�~��r��X���m�C��Z,S�G�qfE�J:��oO���%�Q������fa�B��h������xa����d���-�M�1C�:F�F\x���/�[��)�y�$�D /�=�#&]Z���.H���ML�V�;p���>����>%W������|������Wq
��`��iZ'�!���9(;�ck�	gQ����r.+I��!�D�]�sp����?��j������F���GJ�1�;O�7���j�N��q��q<����)S{�	)���/����o�p;ri*�����K�.a�,��+L]��!Uw��f�~�\���_\�����5��_Y��]{�G&Fn���R�fv������QnG��AL��K��k�0����7N��K�6X����E�D&���0��b��{��D�z����H�D��5^�_D��������P+����c����s�u�f�J�9G�-�S�IeV�	���K���%]6p����H�V|l�O��YB�]�0+��.Jg&���f+�JyA��E�4A/+�V�����+������PnE(W����IH,;�	z�l;���4�$z�t�������'��3��Sp!�dL��$K����O9���u'�V�>F��q,�R��W��,�&�|���6)�bZ���1,i�s�M��B�]��)j�F���$���	+G~_}'�-�?$��!=f�dz��(�<"�eMi�3V Z��f@���������d^�+���>�67?};>#��L�6���'!ebu�3��������3�s��1S�(8���K�yW���7V�
a7t=�����d�_,���R�1��F_��2�H���wD�]}���G9�A��X������n��5[^R�����
2P1~"�e#�	�)�������bc!e�f;'�����4����E~ Nbi� xO~���pU�[��](��O�>��dp������k�`��o4���z+{;_�`�sQ�`��*���o����Q�������2��y�_��m&�������a���4k�c���'�K��i���-���o[�z�e[}�s����U��Z.� ?�4	��+������-�g�<1^������o���&��	�2a��v���
������]8�^]��|J�8�Q�
�����G��"--�QT����O��c��z�jR����g���T�����
��G]���{��P �k=�*MKX�u�Q�>�}nen�K�E�ekm{i}��K�����F`��a���
��t�`d?��L*P�)��R��N ���1�k����j�`8��;c�)��i���sG��6�1��?{���L#�z�h��i�D]�n��F��j��Pq�8h(����~��Y�������>���e1��d�� jh�r�Q��yx�������G5{/���%����K�*���l�L�������b6�������Pv�"�_�^0|�L9�U��s:��,C{}�8����.����p8��k�9�x����5 �Y-<� ��j����������O�pJ�+[gS��K�2�f��m4$�CQ�;��
�[Gu�y�>���
=����w�x9(!
o�W$��#���SY��r���d�>�eOqo@x��'���,�{&Z1a����sxt�cOx�[���BC��o�t���?��$GM�����w�O��f�"<����5�����n��s�!Jl8����?�.�R��xj�=��'�F�eY=���F���L���d�E���F��T�{^K�M��d������~u�L����i���dD4���S�������?��P��
�(|*��������a{4��������������~���u����Y^����[����*C���{�������W�a�\��
�z������������;N��+Q�_{x�B1��%�6��{e���R�)�%Z����
'�r�E<Q�Z���skY.|TD��=�����	=����5�Z����?g2�J2��c9��1�OAiMfH�lZ#C*����6�����n$4����4��$�h��=P<V�oT��hAvT2����Wk�����)��#@�5�$�C���GW��p(�0G(;����qR�QX�����[������1��y���`�60_�5*�nUqV\u��<������l9��c�6e0�^�$P���V���1db9����h�07�	��h�V��k����y9�+��q�|����zGtiJ��JD����c��S&���x�6����M������S8Rk~:������2����JW������:�4�%�t%��a'�/&j��P���.���00b�Y�C�`�DKI���������0�5?�o?�o
������G��5"���X�s�N�F��1�
���C�i�PE/i�����������of�H�f�(Zj�%F5t�~L�����F���b��n6��,�Y�G�QS�9wJE�"4���g}�*�#�G��n�Y�$�G��i<��{�wU���n����q�m�����'�T�%pG���]�9x��,D
�� ��1�����������</���x2+�����G��j��������\�ZJ���v���5b8����,du�w_ul��z��P������S
��k*s
�n�]������ `�2�l��K�B�Pk0�uv\��jPU*+u�;���&�72���{�^P2w�G�S�{�/;�T�f2r���lp~�|����^l����'y���gn���^�r����^����U��b��i�����������w�d�?_B��}��a�{KKw����Rz8j:�*!��(��'ZFkmgo���b%���G�������4�v��+7�G��s�-���~��I[�$`�sk��\"��m����x�b�7}^��K������#S�Q��������Rgt�2~�z�������n]t��x���hZ����\�@��������a/S����*��vaO,����}�"\g�0�r���w��#c��Xg���{X�����%�g����#6��k�+���x(���V]u��T��������[�89\��2����\��w���z���Vu���j���%m��V��EM�c�QS!Y�~���H���Lt������������ Z�f����
������+�b-
�n����}�������<�*{?����E#�6����iG�:3�7�����Q�/^8 �e���?���^~����<wa�x�o�����3ct�����oT��rhr�����U�����t)�}S��Z&�h�Z����{a����)�W��:�_S(��5�'��\�`BP�U_Q���@p���YZW�������K�&��V8���eL�d����2SB@+�k�$�Q�����������=����T9^r��:5�
�����.M���K:���n��yEg9��:�}T_@%<�����6��������5���K����M��g��e�]��!��aMgt��9�K�0�C�)�C:r��-�A��8��*3��	i]z���u��u����.^���2`*s�*8|�=���W��jKBiUN�yT�=4��-���`�7��l�>��j\����Q{��������;u��Hua�Nv����:!�}p��Z��^����������9�����?�6�������`8}�Zp9Hx
co��0��A�o7�n3���S����K���v�rO�����(D#r������<�/����m�-=�F��W�����%�QJ?J=����-��%��)d�3���v7��7��2J�)���ef���:�����;Sp�!C��go���<���)��C$����J8&�,�����<en�
)���9��1�7L��VM����0����,B(N=(a�$Q�t"���(��5��������:����'��������N���s���kt<�,�'lAbx&����vf�D$v�lO�f����`�F_������8!&!n=J�����[���&��O��.����p�WX��W!��_�Oy�k���O�����
y�D� _�c����	�|��g�\��"6�F�,���3��q�3���%�X�q>�X�[�����x	���������hw�j]�	�(�p����_�Wj����x�%�W,���/o�@(e*q�xEa�2l����!(����<����p7�)�2�S
=����-�c���:`������%/��y�}��ey��=������J�)Yp��� �^Z���JU��-������)����pH�7�Y3�A�#����!���6��\F����4� �F��t=x9��������g'+�Wk�h���b��)�3����d�=%t`�3k��m�a��8���x�������+�}`�FW���������g���T�)�SRxO�\���U��3q
�8�N����pXa
�����F��������0��nCVW�.��5%�+#HFX���F
��*�"���8����7�d�Q68[�l����"��B�Wg5�����B��)�����bWf]j)]Y]C���	\��YN�$�>�saQ�J	�<���F^��������?gI��s��	SY��"��K������Ue�G����-|0c���gy���dF
����<�!���� �q96�).��]��b�1�j�\f!$��4$�X����#E�������b�TZ{36]%pt{:�&���6��#��t�������[��]H��D�X��\��85SM��9]�W������7�`���|p1������[��K}C�����k%��.�����|�l��?�����o���^S�s��63��+'�v7Z�uS�]�\
7����Fcc}��.��n�"�+�E�6��\���Xzt��JT�G���\������ ����$������]�gI���&m��O������z���G���Z��2��J���}@m�m�N3q@v���.gz��W�WOH��'�q���d�NXK��ai���5M~Q�}�^1��P=����+1(�bPXR(*g���������.x��h���&U��l	�]hw�1�j����#�N��F�P��n*!�G�;_G�Z��u��\�|��&��`��v���8z��>f�q�B��3�/p.���b0�IHmE~����:���<Z��[�pY@���\���+�yQJ3�<g���&m��z��`g��W�?F�K�E����f��+�?���&��_KmE��1�`����\���
�3v��!;s��Z���%���`
�NJ��@�gB��.$���!��{��r�p��e������������.����:.d�f��{�m~�����A�V�D���S�E���`���d�Zr<���?��$ ]��:0���"�����6�����������m����U�5�F[}Z�,ou��G"���/���d[����%�1�xn\��@�����
�'-WA��Q���>��A��9�h�S}��7X�{*P��cV�'XZ��*P��+�����������0��S
����6���4�	��C�	<Z��D���Y��������\��U�����0U,0v�����#aM�-X���B\r�e(�<���g7n1�p��T����t;���D��P!�����P�G*$�=����*�)s�)+Df��V*����Bk]Zf��JV�u���*�flEd�nGd�Z8%V	��eB�JLk�i���Z!��k�j��j��*�3���,�E8���8���n7��5��
H�6�&�
���\���w!�x;\k��nI,=��kO�-�Q����L�OF�\(\������1����U�����
�����W�$�#�&���5{	$�P���������rX������({-/����F�h����V�sY�ri�Q^�y������w �.�'�mFmE�mM�6<�Z<��);6��K���v.���O^Egvj/[��<��Ko^�v~���k�������������*����&����O���:K��u��
�n��o7���.��@��5�� ����#���0���D��oGP��V|�
�(:k#�������B>j���J�������F� ��YY����)3���:���r�����)��[�;4����s��}x��+��
��	�6\@��-L(p�*.6z�<��%���t�d�$��f����������W���|�AQ�[�S�Q�b4�������eUQJj�<��t3����3pMf�yx�#���F3���~�{&��J�����t:�<�����������,|�J�~�{��^��(��������O����C��������/�7>��{��8�GG��M�GU	�����SU��E9T`%�wX�T�1�jL��j�!����Cy
/�fL^A^�K_�r���U��|&N����u����0�7�oN��7���j1��g��a�=���g���<;�"�����?��Q�0+9ORd!vb���O+��|-a����kA������4�|��v2x���%�
0���=6����#Zk����Q��;�K��EEO����w��iG���5~�?��/�,
C��`��zCe�Z^�R����W;�"��M���!�L�M,�a��,d���gR+���.7��+3�������J�~�tJ����.NV�3 ���N���Ag��FF13@����i����T�4 �6a�MQ�%�-6��1W� �-�#�:�A���gg�(���U�gE(1�k\���Tq�Z���
�r���m�w%l/7������6�8����j|�)^�(��n@���3[�q,lC'�ZWsH�5T@�x��@�`��kAE�H�&_��b�]^0<��O�`P��V����H��d�Dn4��A����#���Y)J�~\DW32���Y��l���Z�^�-g�kb[��7�W�5�{���n8�)�@qT��LC>��@�3��vP��Q��<t	�c�=���q9���b�9�Z�6��k��j���1�D �I�Q��n��
<q��
�\K+�-j����vyo�������<yJ�G��r
_���=T^�K:cM��_w�1����
�e������/����p����f��h��Uqom�w�)��?
q���=���C�?���=\���w��x������]t�pc�O�x�����]���bv����n��� ��77���9C������|�����)�d9e�E���m�v'a�'���
��-f�Z�|����x�8��e�!�nA��
���V7�=���sb����m�����}�2%���c�*j���p�����\P����Vmd��H��x����C���lbr ']2��G;/y������{K���c��
�J���M�z����];���I�]j=����k��H�K�S�������c���=tw�c|��<�i4�Z��~��~��he|��Yk��T�j~s
T���4�������E<�v�|�-Y~�LYD����W�o����{�J�R�����=ZZip��y��TXg9`-R@��_X�����I�
����K�\�d��@���&����
9pD��"���w����<���|����7`[�`S��������Ia�+���)@��)�����b��2B��0a��)�������:���pL��	N�Nm��k���}�Qnd�b@��b�='���=�sn�2!GW�!bM&3X�&��Fk1`Vfs!���/r�fA���o��Wk��j�7�Z��z"&�-)���"O	�����*�MD���8����J��O�Q�\~�EX�����S����m�+U@Q�������M<��qK����6�Cz'�CT����k����Z��g�E4�z�	���������E�A����>n��l���c��������&��}srw,|sr�<���������E��\���� 
�]�a�9p	�b[�`���(�o��bMC@9������C��������kQ>���[��|�G�8i���<(e�E`^��X
��0��������-�E�_����r�}��5VN>%�|�o�?m7�����v�Y����X��7k����x���w@yD$B���x�B���N�Q����J5����nn��:������V�o�������������h������9�ga	,�����5w�\�����t�r�m�b�������0�����}�`���eX.��J�n�I�E�Y����V~�+��U��p������bM���?��],'_)�$nd9��YY�Ja�]�e�a��f.0�4���:�w��<Dj+Z�{x���X#�S%�+|n�5p>��KGU�.�,�t���������C����Sd�����'�.�),���9�)�i�f�Z/�o>p���O�����eT�h#A����
J��(�x�<y�Q;��QC�k��v�[��k�d�T����i��@X�H�*���bWI-F�a���L���,f��3k%�D'��_b	zgs�Zh�|��I��E�V.�]P6a,z+e�"��z�Osu�
��S��4<)@C^|P�5 �.��Y����2D�,5���P�5�-7��vJ>4L�
1�N^3rP�`B�G�b9��$F���^AVh
wvyI��MO���/��������o���V6�L�=%�����#�� �99����&K��d$x�		�=���T���[�������A�#!��%�|\����x2���:���E@�p.82���!�������%����s\�b����.���.
U���Iaj�>���I]���/���)�A}2u�������K�`������j>�=!~��9��:�qC��nO��{�����*)�Jw�O.�������K�su���+t��G����U:Y��(9�@5�A�I>�-@�tZ�$�E����:�8f���:�&�,�B��=������)����	��7EV#g�pJ=����P�@�rR~x-��o�/H����`	E�r��3���DJ�]�����/'//_����^��!��R6�K�����
|������r��e��\���2�������e�����J-w���
��k�������Q��|����yZ\���`�_�7�
����D%����0�@o�	���KS�e���0�S���1���V1�m��\rKa}Fr�,Pn�/4�2�m�����e3+)���2�����b��pK���ce���"8R�t)8��h	�B��5�������|�v[$���!�#�5J���^N�P��p��������0M�g�'A�]P�Kn=[t�����Gu�5���(d�L\���N���u�y����h��~��'T���*~>��@�!�ER*��T��0���N���l�#�^3����)�����'�H�����k���E�0���&�Sd_�`N�9��)�(�����JA8���E
�dp�vF�����+�0�gp�P���k�{���Zd%�G�+E�R��l�1*���K��X�0�7";��Vs#�� �:��6����(i^�8m��
4��`REw5������v���8��w���Hf���U{@���G����8����C��U��j�!����P�^�������i��1g�`�I	�#����g�*
J��"g���\��v�G)S����S��a��8����|����S���#
[�9��0F8����|'�;/dbA�JqhO&�t*R��[NEQz2g}i�~������� �t^��[:����S�5T\(�'���zy������
���R2A���]P�M��d�xUn~�70jk^
�	����9�}`I�C��N��Z���<��f�d��|~���f_��3|�s~�'�UBI��i�k�����9(t`���)�)jwd��*�*���JW�2�������JL�:Y�4���\��Z��p���[�(d���8����_���e)������|pN��N�!���m�1���"#�V��%7�� �7f>��K��z��Q2��y�>�lU�4?��P�"�[��o�OX�s����"������S<I]!Re*.��,��&����Y6Eu��5����N���Ym�E�*������h�����y)�j�-lQ�����)���!�6--�_-s���3�4����tz��7�w�Q��s�>�c^dl���}��Ln����n��B��1D��[����6()F �Z�"+�v����[�LW-#[b(�S��T�;��M��(���B������E���^>.��;b�������T�^���w���<u�tbT���}j�."�(|]@0�Xc>l��W����E��WA���u�	C?:x�@���M�����������Tx
�U��j;	z	J��Q&\�2�u�xDW���Z�����X�^
Fg����O�_��h}��������du���Y8���8E���R9�,;7oJ`���t{�|�������lJ�~VV2�.@�W��W�����i���N�)�f��I��Ip������O�,n^����?�����F����<�m�������Iq�Ew+�V
4@X���Vjr�'����d������p�?f�1F���g���T�~�x�u��������<�&��	������~� �6��)��apNW��%}���glQ���(�����R W�`��	UD����rB4Y�P����o�4�y����n�\������|1��(8�E��i����!������-g�;�����Dx�/CG|w���n�t`�7�R)�xL����@�_�M���|4���;{G���4��S:/��G���B=�3nz�g�^0�j;m	�o��qJK������Zh�O�=
!'�l<�J�?@	<?���-�XyZ���cE���������{f$��mh4@`L��l����^�?#����E��~J�86�!�����E@���~G"�����T��%"D`6	p�Nzo�l����Ix���/�f�����q�\Q*�>m��1�H`Pl����e�Q���3`�F��%��p������h��jsu�o�0\�����[G������k�X{�7Z���fT`����C�Fb�h�g:�����\;�
T[i��S�4�,W�M�������>R�G�y��Z��N`zb�S4�f�1��Y���	�GQ���PN��'�-����*�.����+>���s5�80cZ������P��"��~��It��O�����a�R�
���h��B��'����(���E���/������t�e:�2���L��v:��g��p�6!+������=z)����U 6O�g�s�zq�^�,Rm9�������	nu��l��53�[YC��c������������t����c���g��k�U�&��1���$����B�I!���^G������d0M�~P]Z~�N�5e�z���&���K�7�����lQ���k�fs�{��VK�j1@�U������r��}tEq��l5pOT[15..l�O��{���{�����l7o�E���D���_��@v_M��P�����d�t�%��j��-y\F�����K��h��������l���w������<j�d�Pf0�J1�L�;��7#��3#�Q��Gq�U�x������������y4��:��$��%�!���Xj����l�IG(g���}-��2(���k��-]��f��e�~������{�}�aq�l����o���_}?�F��wct���V�v�&�m��b�*&P��*����
SF�h�9�f�j��o�UU����$#=��{KD��In[B�.�J�v�{_�]���J�yz�%9��;��mv~����O�t���RW�
�#9=�z$��*65G�D�>�?��94����{������bT��?��r(�bv��;�Jw4�H�Ql����Q�X7f���0n���K��M�}�d�����$�5�0#�)�(f\��[<��.|����]��?�M��N,�J��t��q��	OC����,�H��U�\Z���
o�����h)(��,���4vv�����h���n0�Z�����5��i+�*m�����b') ��1���������/�����
��?��S'�/���lE��y'�4���������~��m\�����6��.��"`�2���"$]��f	j%$��J���,]�@�������ag���(y(G\+�7��.e�<G�����Ug�[�D�Y47��)^4h�N�%o8�o���������!�^I�����3�a� scVn4��`���Y�Jm�s2���Yv�\(Z49vip!gNj�����j�������&��^�v�3}��/����v�h�v�}���-�E���g��t�IF�s��������k{��z����lb��{����?}3��h�� f9`��uI��d8��H��1���Dx=����;!�/;���)M�����7�Dy��Sn���W��rCEf�����e�?8;#���`F�G�I��,��M�s��Qx}Ig���y2���6����Q��(|O���\��!U���v��`��I�}
o�on��>�4�G���#vcH���C�Y�����\oS�������o;�G���������]�b���6{R�H�Y,�#wkk^��z�fw������������%o0@Hxv�x@0���.�
������[TW,/�`���K�^w���H��*�����\X
5���O{�����S
����/=�Y�n�M~���T����������.��z�FB�
o�����:�	����F!\�c$����!�|�cs���g�"Vd e������>/t�^��!	�\���O�����{s���6[[�W"
Hy��]BN���y^t�		z=j���}suv�.�Q������K��$R��'w�+6d��m'L��*�r] ���pl.r`�9�������H��m.���nT������8�����M�j����l���n�7�DW��j����(t4������=�"����7taIWv��P�"��xR5�\��9�p�����`
�K.,b���������2'6���r�UJ���eK��C�n��k�y���z�e�K���$(CIY_�����w��r�oH��������x�{�����(@���vc�W�:$�D���h�	=�8����f�
Es�Th�)#�|�o9�LK��c6���N�0����^
h���x���[v���d�Q>���}h���G�*��5�:�Lg�L�!v���
��j��U��Y�#��=��SD����EHf���[e�F�UX���D����[�k��M��[{"�y�}>p�ey����QE���]����eb��s"����~�-�C��P��T��D� s��|�������hj�ud~����<�]l���\g��_���CO���F�!��p�y�/��f���������(���Hzo���S^��+<{1����k�g���y��r{g����S��Sj\����	����#�8��?�=&���pr��e<Y0��|�}=�������S$���(K����>�R�Z�����@&#Xp���O&��jB�J��pFKM{�0���k'�{�� �6���4O��(�tj���x������{��VJ^�c./_�����X_�`���c�dFS
���������J��������[9����0���V~����t�'T�1Bd��9��tkr��L���I����:���r���:���;L�����5PS(���l�o���y�oPD����7��H��r����`�%�~��HXx:
'�pZn��_!���k������B����N6�7e}���22]�A���1�~�������k��sZ���sg�T���A,b�����tn��ft�8�:�F������i�`�rA�������btpQn�8Z�f��/�.�����(-yux���[�z��Z����-K�+�U)-���H?�=��o������M�J��u��I"r��������#zH����e!��������z���U���
y���|�hgo{7w��{j������s��k�)��~�[�u8B�?<���?p�P�`.:�b��"�2���x�O�o����
N�g�1�R?���1���S�c�h������
�/�����xz��0z�[��V����x��|=�������o�i|�a�X8��o�����������v$��q�������|E�i9��o�OO,��LN
M9��\�\�M/�^)Kg�
��?�!��	�����)���� x��Y�z�j��!���������d����p$]yf�M'� ���7X��}	a"!�~DB��C����W��x%>�������������>�S�s�w=i���q�������Lo��C1C��jy<���w� ��EZ
J������P�f�S��nL���@S��H�\��O��+������������g���������WB�_��2 -�0��������W��#��SQ7+b�P��4��#q21�Q�"q|�����>��
�
h������gp{���������<r5
�[���9CSS��������FW"�3I_@'{�h���;{���3M��������|���!�e�=2��h�C�^�E�`��
�B���[�"4���B ��w��=�<oI*�[�*�����@�� \=N����
y�[pFf�����ep����0>-������7Xa�-�xO:���'M���uB���-���e1=�1!���U�5P��?��IpyNdFt:���No������LC��QC�>��d�b|�*��9�i$Z���@�u�bI��M������2/�������!Bkd^l-'ds2�^e��l��n9����F]��<���W��"L4���b���Bs���zw}!�U����_�������H�[Gnb�cQxPRk��������u"�%\@ s\<�$P@��0���-����4����`:K�kWF�_�D�x���b�������(=��5����[���f�x�Rw�����Rr�c�$XO���z������X������|O�R��T`-L�@X-�	(mJ[��V��������GW��(��$��'}v��a��G��~��GehY�r�T��������e�
���	�%����)�b��M�l<�;f�-�����6o�����x��DE��7��5��<11��Y�Z�H��'+��a1��Q��L�fT�j�%�����T3F����j4
��r9���g�����$�RK�����7�o��&&W�_��q�Q����&'E�Phy �$c~�[��#t3��F���z��7�3�Q�M�@@Y����5������eu��@	p��j=��*��� "���'q_��mY�bQK��z��%X����H�tq���Z��7'���
��1gQ�8�����=r�rZ'S}���_�8�K�{9���T�c?dlG�����E��U�Lo�q�&�y�M��������}gM�����	�Yt�h����l��H�R����*&�����r�t�"qF'k!��nZ��C��w����=X�<����'��;�l��]�W*"M2Y^��P��H���3�52������`���-�NH0��RZqRD��NW��)._&?�Aek^����)-�ML;N�-z]'�u�u���&��zT�,2���b��7z �i��2�,@	���Y���aHJ�W����0�����aZ	�l� f\�h`���d�jd�XL�<����~"�)U�T�_���s?�����n�|T�������L-|-�3	M��������-e���D?���Q-�BT����dT�%bR����,��
K>��qpE��p�p2���O#��e��H���g5����t$���V��:MV�,CA�=oU�LQ�d�iT��e���N�2&��qTunmu/�ja��S���|�������h�S��"h�R������AG���Qp����:d���-�b���t�,��U����e�9��0��
��:���C�����CYA�)�j28�}���b]�����S�B/����D����A����@0�M��aC��&O��oJ1N�s:|���#Q!��l�U�6�+��������v��e�:����<-�#|`0����"����D�
��D8e�PQ�6+C	T~���d��I�.��[�m�T���gK���x����d�3j��y:�Hc���Y�����������\,�a����U�����c�{mY������=?���F{w����:�(52�M�<�.��[b�K�
�g��_��{�h��3����$�:��^��i�<����l>�5�Mr3+=j��]�����;?{rTq%�������C�c�5������wt��3�A������x*�E��SQ���Q�8�W4<��w�~��:;��k]q�(�`N�Nw����-��k5o�T��`��
�������BW���K"z�<��jD&aE�hne��D������RAIo��(26%~^J�������V:%g������:��?Q��������Q��.���"�����;�;\A!*7�*.�^
���,�p�y*��#A��L$��a���k^�2���I}�a7���������-�^�8;lB�N;��E�l�6h ���MPdM���K��M��~������d����`�p�F ��9��o���ro~�����/��P����V1����>�G�'aw�+��6+E)���Wqi�.�	0�'6�b��s�!�b:�
�^[�-�Uvp��*�MJ�����TB��eIX�����)���
�7���"z���9���4��K����i�v'm�z0��E�aF?��l��B[g���Y<X�R&_.�W���q�v-D��v���}�\�%k/�1}P��V(��7��
��~���'6	b>Jc*&�P7U��o��}������o��Y
�Q�G�Emn����;kv^/������;+�L��Ko���\t[ ��
��~���I���a_�!U����
�F�h�n�q�T�8�d�A�&o���b���X"�Jk�����Z�h�T��iM��%�����!���qlb����F�?�fR�Yp_�?�f�U��O
�4UW�ER��*��d�8���^&�� ��h���.�.lF������9��N��Dr�iY �~6�.T�����_^W������y��@���>Cr1��"(��6����n���a���~����;�����m�����676������y�!�p@�(��7i[�y��J�p�t�x�a��Q�x"��!�t{�#�C��	t���Z�p��>�S���A�����n]l�x�.(��,���>����aU/Pf?����Qb�;��;�����p���qu�1�.Gb����t�w�B3r�����v�x�nJB�<���I7����x�����������x<�N�2sO�������p�)���O&�+��2�	$��OSdA��������.��VZ7��h^�j�a*m�8�x~��h��k*��I���6���=U
~Z�������[�h���X:�o����<���g��xz}j��`z$��Y09g�50
s�������t���g��S)�jtuR#��{�,���k�k�x��-�`�!�;���*�9��2?'�M����LA�� ���D�~��#�����N�w����z��KE�NT_6�>������0J���Yg@-��{��.;B�{���E�/��4���f��D�f!`���@a�}�V����17)���\
S��{W3~���nXf-}��r{gOd����yYV+���P�����]���]�������q�s J��=�t������^O����SM{�0�n��h���E5I���M2���j��;����\%<������9�,��y
��P�u���|���ES�<h��BP��\������[9����HB�����.���3F�lt3G����.��0�I���;�p�Q^[��U��{wG��������_�q�����n���������F8<��=�f��q���������
��F�+���I�k���v	�q�e��/�I�a+i�/���eL���
n��\��}��Fs U�� ��� fbq%�J�s�UZ���v��$�Gh�����<��
��?�qj��
KkVJ���9��5G=(v��]6�p����I�Wb>?e�����c��8~m|Z1S����z&d�����^R�>e��*����
o���B?�SN��0����	^<���7��-�SR�$���U���V��9�����d�����m�b�?�����������h%����	����c���xk|��]g��0z,|�����o��I�C��v]u$��q������"R)�����w�OO,���Z�[y�A/��`c������2��LB-�P]X����V���$���w���"�W� -@Ji����\���T���'�x���d�[^��<3���]�vT�w+��(\�	-G~x�%bo�O�j��+��W�������'��N��������<���k�����'��]��5�����l�Z�����b�X���4,O���\�i�(D��#I,���7����:�W�n���^��g���������'�m21����������)���mG�?�W0����xP�v�Q��#�k���F��QH�-F}N�a ���,
Q�c)�9�p|������l��
�
h���4�!38�]��o�����\M��V<=J#�xb�YF��$������$>����u�����h�5����s%�Q?#����WL7O��h+�!o.&-�S�7�
q*"o!��������<G�)��\�;��6����1���E�|�@sC�7����z�L��gM��C'Ln`�v���gz�@"D�n��{�	k�3��_`y�X8Z��"{l!A����`����$��'�?���97�j���v6����4���v����1����q��r��K���0��P��{B��/<��6'���h�P���8��bnt-'l�2��������m�%]��]��<��7[�jn����=
�p)~H���s|��]_������g�4��E"��5r��R����Z������.Z�����'�Q�'xV
�AlW�7���3Y���4LgiAl�
��;���(����!D�v��!�����_<�\�_����-������g��I'�zX/�3���`}�/�������x
��
��k	`��j�_H@i�P�*��
�-�� �}�t���I�O�������&����K��A��Z52��F�
����<
���M6`B�/�cV�>��-���x\��g�-������^�����x���#��7��5�[�������L%M��S>������m�,X���VB�)���R���D#Z#_��j���v���hNg�r��(���-,d��mM���	��sp��mb��8ViP��
�In�qZ����\2���� �� �7��jtH��GYz��>�M���	����?���0~x�TW>	��a�������O�"j@m������#/5�����VIm�:��tW+���oN���j*.!��������<U�����~�������yR�>	��M����~�7�����U-��Q���u��s7��mCf���I��;k���x4�M�X���G���vd�<e��"�L�
�9�u��,h�2I��\_ij����������#3j�*�~�<��P�d����j�JM$K��RrR5��+R%���{�����]&,�kl�vB�)�������!��cT�OLA�6�,?�lm����<�E�i���#���f^�o���&�a��d���D�=`���C�A����q�"������0$����p�k����G�a.�`� �fY�h`f��d�j�d	6L�<����,�`���H���j�z��������Ht���������dj�k���i
dE��{`Y�H����,��~�X�;���u��x��d��K��	�|Y���e��q�E�p�o2!/�w;Q�R	j��T!��)C�[M!r�"��E2T����N�I��R�=�����J�&������z��Ia���2�j����%@Q�!�.s�v����v��xr��tJ�_
^JU����9�(�~:
.B���S�,[��e����R:��^��~����y�mH�Q��.����a]�ASl`��qkD�2rC�u�*���g`�������?p��&<V������6��A�;Q�?	��~�96h�`6���3�FM�X�������t�L��B�g>�h��s�W�_;{���#Bm�}�J��S��]3yZ�G��`1�HfC���i���i�p���y�����"�K�h�-@��5��1fU����oc���xs��
}�l���D�(��k���$A�}�x���m-���i��=�m��m����=7���q�x����Ju�=���G�Q��'�{�y����M�v�r����j=��#�y�����*	����(kV&zZ:��@f3-�i���'���a��N�N]��5���#��3U<��D��D{����������<����"�����q%��O�������a8T��b�A��|����.���	n�����)_��#S`�g7UU�����n��P�����U����������o�v![j��>�d��������������]nm���f����F3��}~N
|��TJ�a�r��9�	�������]��*���"��+���W|)Z��{r�!J�������BC��@%�QK���'��)y5F�������j�
&�A0��R?�C�"�\��u�������s�_O��������`���hon�����=J�3N���da�f��jk�J������,a$_Cy����zA���/.�
V#�K�
E�a���<b�"X��bE=�dC�����
(��:F`��Fm��m������Rp'�i���R���*���J�`������:A�T��u�.o��p?���:O�~���w���>���tLU��-�����C��])�R�����(]����I883�*)��T�h�t:5����G,Mu�4Q�h>�=�
3�[�O&*�
��J���=Cm����6��$f�G��$Y�Y5�&����d�8@[�����6���C���
�T� �VqJ�W��0��4$�53���5��m`�BBb|i�Ki��u��d��P�d��]���3.��;2�*��.I!#��t�M�A�����+�7O�Y�^\'�`�����&}o}���S;������N������������>��n���U��O��m��8�3���K�`b���i/���2�L��	���PbK�e{rj�O����D�\:�Kc]N��������/�@)��j�L��`F��!n��v����E�=G;J&�����g������]�8����y�W��j�6��������V{!�m�������������.����d�TH��h�����j�	�%���.}P���\�}p�+�(�,/Q<���_��	tB��w����R�k
J���h&-r�c�������X��(3���lLCsIZK�����&;)��^��v�E+|��F�q�)�����������~r�+��[3��5V\�1olhq@�#��9u�]gj�����JZMU0;�7����]��y�L��������/��UG������� J��������d�'-G/��$hR�{���^�'O�W�6����k����URmm�j������~������:|
���J��������R��R`V���J��\?�:��{��CWg(-ii����i+pn+n���SWX`m�g���j��Ep>�4��nZ��� &�"-���ya�c���_�Kt�_}H��iem}*��y�[
�D��>~�����C�m>t<�CZ����t���h5��MRm�Wk1
�V���!��FX���U�e8"NV�j9�p��\�M��)yH�rF�����$�@��MO �r�4�tI[��:i%���a���������}�)K\^
��R%���5�&�"�������(�4yO=����5l8�3<����5)� T��b�Ao�����8��!^&3�X�A"��]LFrm�s��eI7���0\E"�����B~?�k3��	O�p�����k>863�����^�
��
��C���M��I�a�������XYG"��2��qT�d�GV�Z����g�yzw�G_NN��h0���H���������n����Y��N��1	1`YQ	��,.�Y�<�L�}X�����S���r�������������w�}���dL�Yj������!S ?t����*��;���S���w����6���ZSy���?���"6FF�P�y�������=8�5����Nj���y�>��<��S�O��c�[k�
R��k^3b{����Fc<7r1^~����`LnN{�p�t�a�2I�l�=�O*e���
���<%~~�EP���J����0P�L&7�<g1�gW����.(-�4�T�����b��h���I��sQ�
6���-C#�'�D�{#��FXHm����������}$�ou$��G�]UO�����r �l0!dD�&��X�g����~�����z��=�#�I��Yk�QQ�l�����c�����Z�T�����
L)��8[����4�u\��]��C��<�y������?�7��^l�q��`[��3G�q�@�Fu���%�ay}������3���n���/��;�O�����T�P��o	��x�A@��4�3�_�����q$��^1zkz'M�./��Y��1W�K����hx��
:�J���C��?>�>�����e)lbbSR
*I�z���N:G���D.��d��
�������<Ue'r��Q
����#�(�Z����b8��dW����	��J��7��gg�k��X������BD�I��0���S��3h*���������c%�������U���)p�����~
����.�,X����l����z�u����T\�@���039���I�.i�T�j�"��],�3�s���
���N,d|�H|��l|���l�\�D���D_���xakO����R�Kyz{n�.=!1���Q�;Q�~v�s����76�CW�[a(k(�Z/��������G]]@<)�������2�B����/.���,����hD
!H��E�(��
�����2�E@J����q�c�G_�F��lk�-a�����-�&�k�~��^%��,]`���'����r�(��`k�O�aY�!�5��7�>��S�����6S����K1ON6�9�6?���{<k:6�����b���k�}���`��P������
%\LW��;)��/=����(5�C*�s�<)�]&��)bO0=���ne"����i�����������=��y�k��F%Z�v$G����=f���\�B�i�#�HZD��9o\b��X��{�����o���|�i�����_���E����`}���wb��HQ��,����-�:e
6���!z�����Q�l��'��$�8�41rD����_w�4�W�}f![��AW��&�����U��L�w���"�#	�P-���`4w�_.�����I����2�V�m���w����_����,���2>j��hJ-��M���������l���h2%<�-��o����U�z�<�2�����3o�-vw���Z�c�xwI�=o��'!���}��hc�f�=�?��n�=��3��M#�\�1/���}��k�=/��a�7���6�^{^T���t��w����Kkj|&g.%��x���t�m��>��m�CV���'�.��Q�[��Y#Hi�d)�e`�0[���N!�u��������L�{y1Vt��bs��0��'St&�L��g��(�[&���Rm����~��&.4���q`fG$��q�9>>.���w\:��XU'��(U��\��PJ&%Rb�+����T����
M���lY�~Y���*5R����o�R����A%[��-���e���@��h�.�����Z�����B��iR���`�rj~j�Sd,�w�����|���;<?vG�iilO��GX�Y���(HM��BV|<��-O�]uY�n��f��2�m<�Sp�[���*i �Y3��;$;_�W��jD�:�M��|��h���~�|MK�s*�;��t�Kc/#D��/�����������WU���	������?A��v"W9������v���>M>Q�1��<\K{�>m�Dj�<�>+��@�*�B�<R����##/G�������i�@�y��D^!j�+�r1�����v���x��1�M��m����O<������6���Q��G���D�6����:g5.�?f����� �:4��z �����W:���9�x�`��Tl��R�r����8@�����[�H������#���9O���]39��!1��4���y(���5S;f��n���Ge��d:�O��u����F����^���3O���f��dM�(��8�����=a��=Wu'/���.%?`b�-<�Q#��	�������S����~�*�}�{;^E%Pi��,5Wo���i{bj9J�M�F}�ODL���o�;�s�9��&7Z��"�K&��'��Q����o����b��~�Mx��]������w���I�U�">&��\]8���X�d�x�j��o�u-]b6����p���%,����N&B ����'�������?�����I+��K<I�R����y��z>%�O=z��gxA��z�P�����������]���Nn�
�a�`-����n�BI�=v�*�3��A���x���Y^��5��	���H����7l�i��,�������?�(x��L��!�6|ic3o'���(��/����(l9e����[���/����+dsi��Y}�)8�+exL�*.�E�Z#r�8�Jy��Z����A��E,1�9O��U��@�M^�^L�����`
u�x��*_��:����q��JMp���#�I�\=7A�������k?&�����F�����6�5������J 9��N�%�;)���M�����D��^�����`2�ly�7����?����6o�f�!x�R�����`�/��_���y�I����~��(���j8�����-C���bl��Db���~v��>��_v:������ |O��)��w	$���Z�v�3N��U��X�H�5���L�x�g yrI�G�����+3s��W��d������k'A�[vST��$���dH!.��B��[R�"pN��n:�Y��H�fR�"Tq���}�Wn�^��LR���V�����'�'�!�rb[������w$��P~l��O�s�*�bgKt�S���p�+C��8��������+��c���O	yq5��t����D�t^���F�{�@�X�����,��IJ���'g��o����F�$���@SN�:����L��4�����2��H����ABe��&�P���`��
�}�1�����������j'�d�D�@��D�0��v�>lX�(j��hde�	���q���V�M����n1"E��vd�Y_�ydu����	��E��O��'��Orj�}����#��>��/��Rd������/3�q�k��?�&�W��&�d��kg�dY'�<�KL���b����4]g�*�8~
�N��d����i%���a���WC:,=Rf������0z��4>*uQ*�0���l�?���A��@����
�$:��3]XBB�|Y���K������X���y0��$c3,cP�Ol��7I��3��8���$v����T\]oZs�(�9d��r�q�Cvj!�Z�4��nm�Fu������ku
��s�@�=6��.B�����[�K�n���eR�L���,_7��r���P�LC*i�^�i�d
��*m�&!��������������?�2����a��n1����B���#��������+��!%�2����.��9���&)�V��}������3 bz����o�oG9�w���dW���5S%L���[�|��cXr$������Jq)�/�����N�(���X*(������(�g_�����o�����w��=�/�4������T%Y^��:��Y

���(�}�x����+g~g���������Q������~Us=6=����h���1�c��%g����\���X>��@n�<����3�s;)3Si�����gA
heWB��T��)�A�����X#E�?1)n�	�I����l&�d|rR�OH�Y�+vC�nI1tP�	u�\e����9
���f�~��������Dv7��O�����G��TcN�4s_�1������F����h"���h"���h"����A���|~��v�T1N�_�g���
�Tv6Q�P-�Ni�_|�S�?_��{'���b$���b"�����N�i�|1Sr:Q��zQL���&��,�On|r���������v�'�&�v�J�I���3�{$ ����[qI�{r�S��_���n9����bB�Sg���N'�`tS�;^D�x|N�2�^0&�{i ���O�"n��v�:�AY~r�l�Z����������8ci�P��?� 3Dg���T�Ss�1Y��[*�Ca�Ra�	��_��g~!.�(��B�e���&`"��o4 d[mFV�v��$js�WD��`[���00��������Z�����P�1'�LF+y&Cm��������3<�Nz�`U�h�O�����T������6�_
C�u(�`0������<��^��m��Z^�x��Z���@'\������#u
��N��}U��4�D#S����������|t
	wz���,��4R�G�r~�#���"�_NIo|�? �E
Bm�������d|uI�gD�����!�pH��_���3�p���d�)2�~]������{*�?���T{�%��%�S�GW�z@r3%C�@p�ti������V��Fc�����Y��HZ������Cm)h������f�!vX��r��R�T:���#���gJ�����`�h�����b0��^��
Y}���#��}b�������g���~(��uf�}�
��vv������{��vZ:����Yk���6��T�N`�_���t*��[��p�qz/���F��fr(�*� ������+����5��Tv:�hK���K�%ZO��<\+h�\����[��`/!�oVN�/=��^�[��d�S�Cx|���kz���0��"������J&���*yZ�Y]�iZk��F+��j����m�N�4W������Uk�VO�� ���w���yJ�w�.�V�����J��;%�3'D��'u�R��y��:V����������K/����#�����;�������}�xrxQM�6�<u,�*��>JO\)xs��:K8�e%c`�f��)�W2�U�N+M�$�r1�r�?[���L.�W��S9]@R+�^���-+�����U&������v �EP�-�� ��Bha�m!����#R��^�W��V���j��:����t�WX�������Z2K�x'�P���pq�,R^Q�Nj���a0���@Vf��z0�M���R��=py�dE�.Td(o����>90:FW�pR��B&���\���V��d|a��M��U�n5���
y���T�6�b�P�`��������Pt�L
��K(]u�<�F����y�����m��n���#1\7T�hF���D��j��#�]1�a	{�����We&��Z�f�e���9������
�I8���s��M6��Y�o�K�IO���l���y[�&�8L�!x�k���/^sn���!�S��e���4+��fP��@��p!4-��TO8W�Y!�C;�]�BY�>H����.��vi%!��T`u	��k;B�D���<��}^����!�:27�p��4���JGN����hX�)}�)���9��Fg;_�G.X}]W��A6�������	\���������v�8W�3'LR����Z�R���(8�+���&Y��h��cna
����
�XQ�� �p2
&7d8>������ag_tB����7�y���`8
���hk;vT���	)?�����7�W�|���VA�P�+�*�<B��H)��{5�����k�H������BUH0%�k�IXa�	g{���e��xJR^F���UZ���._����j��oT[�N�������Z���*s���i�Cya�c^l����i�d3�Vw!��T�
X��o�7���"M�F��^���S����������c�I����wD=�'�<b.�)TNm����������,�������tS�;�T�s�n���c�oH�	�,m����<T�<��^��A����x2���k�M:6���q�?�*��-�&���z�aljf�z�����<L��1�{|�Y-��vZ�EV2����D���=��yXM��B��@�R0��`M��Y,����@��Q��F�'��%D�������'T��.���#�'���rf����V@��rp��kUk�H�F�Q���R����_
��63�T�FP��,M������0�G�]N���M���S�������[9��K�9���>��� ��NPd������6nzo���5����7R�~gm��d,�f��ttB�bN
����x�	N3o�0	<����V��]�b�I"�[O)��W������������b�k({}&�����x�-���y�{~+O�-_R+d)�D�D��VAwZ��4�tPY~c���lL��+���x<�0�E��t����*�F�[���v����Z'HT�������H�������P�h�����5d4���9��&B�X�]����NC
j�R��)K��F�FVk�hB�J�1�>�9 �������1w{b�e�v���3�AgJ!<�����������R��-������	�����t��|6����Rb��[��J�u�k��G�I��Uw��t����y
K:�c�����[9���|)o� r��\����\���\���
�}��r#�q�.���}nH�R	���?���b�u�Y0������[V2C2S�jAt�b�}�g��u��6H�x�������
���H�n�\�����"RM:���#��*^���	��.~���G�P�H�wd8�3<����5)�O�m�d��.�B) �GJ�l�����S�����\|.�LKY"����,�
.r��n�\�����xd1���6�[�R)_q��j��u ;b�X@� Q���������7[u�����>cT���_\�o��� c�*Pj)0����e���"fV!�����'3�&��[/w
��T��[~3�v�����[G���@�Z]3��ux������D=#P��5�d��l�/[�tm���I����`�Iw�~w�Ha~��������V������
���E(I��xj�*3�������/�����G��~x\
g�����K`q38R��V$6�'/v@�!�jka��`�5e�+f��g�:[�{�x7,��.���:���l�2�������Aui��:�L��������Kv������V�EuW[��$���?�X���N�b���V��~������f��j�*V��
�FLe�?�O��B��2//Ng�s�1�0�G�c����bG�����>����5��*��b�)����I����p��i��=Y?s�@�R��vR���>�_�Z��B����������o�����7m��HK�=�+���-���s����~�����IO�j�y��8���[�C��x��O���(O�J�������?�-s��&[r"91Mg��e�Q'k�6��5->[�DN��������-r��XorYF�|�8#yL��%�{��{sp���2��.�G�o�c�=|��1���g�<kFg�Zn~��Y���2��i�I�����b5B�DJ���2��s��/�����8����0��U��J������x����}�}"s�L���zY�f��lDlE*��WO)��f8�xC����|���K�J07��x��aEl*�$����VM�^F�'/����U�)?�M��o��OGE+N�����d:[���a9��G��+SdR�to"s�T��L��+�<[���~��UY��]��
g���;'� ��������V���/���g����s����6���9��V�(7w�<o����}��w��m���Pa�����zw���?x���C���/��5�g�jtofa��
v^���Ud)c��eW������u��������A�z/�wU|������{E�by���%�3]A�q�����������}�������������HB�*Fx)$z��2�tzz1���u��R*v��saC/e7.�8�U�	�FDh��<m��W�+�V�)`2���/��j�n��s�F���k��k�tJ~�Z��+��0y�}x�#����fp��w~��T�Q@7p�����x�S���@S#{�>�F�Q��9������x��C���)z��Y��l��,��6��6��2O��:3�� A^�T���������Gd��=%�]��\V���jfM6�R$�
�Y:l�5%vTJ�
c!��������bdCR�V;gEZ@�h�0yb����~KV��j��'��-��
K�S�(���Z����N�jR|��V�	`R��3tJ�Z�����Z)X�/P���-V-�(s���1�9.h{j����x[��y0�&�<�
�gD��J��\�~]\Wa���l�i�nx�	��6��9��F���QK����m������}�!��_n���8�d����?���2����#������Pg���a���9!�.M@����EMer�_q��e��/��L����/��4x���,3G"Vfy���|u��"���bu�.����c������l�����R��W������(17����DJJ��3K*�Hj����+N����?
\q=�i%�.��,��q	E4*�� �����G��}�yP}q���~?G���N��N��d��v[�m�c��2)C^iRA?C��$����W��X
���tN�Q���f�W3��i�_�L-�
�<%��D�fS������Q���xO�������>��_w~�Fk����c�2��_w�~�}D~=�~��s�Z�<��{�s���������=��������a����(co�:��_"���p	��o|d?�u/~���%�-�T����������Jy6S*cZ4�J$�r��t5�^��RV����~C@�C�������)A��x�/4��#�W���-Kfa���z�
�.5�{*$�O��(��������(��rr������
V��2���&GB�g$We�S�����z��s�0@0�>���> �G��|��_�-�D��$����>gq*���
�$8�����m�n0�����j�>#��g��O��
GlX�I��aa�W�%I��X kP2�<�v�Pk��!�Z�gz���a�����qIk�Q�;���L����4g]�Hdz.l��0m���_�5o�+�8Qa�@�h�lXf������9 �}Yn�ZZ4I!	��c��0����Z�}�5�'�5[*�C��C�I�`�8f 1?
�+tuN��9q����B�u��4��-"7�M������q��T�.��O���'�t�E����6��;����p0�������6��a}u���I�O�l����]MF�����9��UG�g��@~9�[����k*@�G�q���	��+@`�Ey���t��*�5J��w�U�c�/w�U��[����.�7]�����H<��yb����)��B��"sNg�r���J�+7��$�������o��&t�J@�A��"�x#2f��V<�IA.�U�����trJ�1���H�U��e�x�ZVW�����!Mfr�>��TNM�V7@].nn�Au]@�!�H�C^$����yX����h:�P���5������?��QJ�y�^EK�P����3���5j����������������;�~"�*�9dFGvE_��4������P�:�JVy@�x?0�T!�_L�w���V��I����q�nb�Cw�|�H��-xa[_���H61�816��N�d�Z�l��ox=*M���n�u<�I������Id9J�x8���]��1���7��!�th���'���N�����K�~��s�QF��(����O�lB��e���<?=g�6[����?	��~�M-�@0�M��a��k��~���5	�iC�SD��w�98"�+�-c��������rT�
�y��,9j�������X��9�6e������T�aN�Gu,P���8x�O&��n�%�'�P��Ozt����*���Y��P!��f���]��<�`d�+�Xx� �{Rq=C�EI�Y����������
�����B�'���9g�Y'�b��l���6����J���83"�t{+�:\����N�e���N���x�H�T$:u�\�����V�Y��]�u���V��\!*O?o$)��7��\�[�������km�F��B�&�VUO���2���~���9�L@<�P�����~ai����:���&��P�P���9����P�`6o�����Sw�[�1_�FW����E�h1p���dsAt�<���
r����*��)��tkus�F�wv�}�tO+	��j�����n��&�z���{����]���//�m��{�
��#�4�e����B��w����������^s����bU5��o���c���:?��� �����g!`�������\rv�����w�T���C+��)���)4��������q��N2������3n������AIN��i?_g�@p��4 �]�JI^��R�p`��/��Ft�alX��D��/��C}�~R�]W4O^1 7�(7�52����6k�_-;Dv?p6��{:�v�����Oq+I
�����5S1��.�#h~�����*O�`emQ�h;J���������:K�9��dQv+�a4�AxN@�l �����olPr��V���qi��j���5	.������@T���h��iJo$<	���9�,F�p95'L|����N|���,���yB��f�Q��8�����x��x�C��5L�1�o7w���nw3lz���v��~��|�~y���HMc���ffi�����X���K�9�X���4=h7W�UCi�<�]�D�Q����j5�C���c�U�3�j�5��ae��Z�����3�����r��|9W������]�����]MW�Qa�R�sO��u���-�������[8���f���XySzv�rzv�$����i��/�g�1�g�XbOk�����5�R{Zk����R�[��s�'��=���=3��A�����3H�����|v�=�g�X��njF��c��<P\S}���;�g���X(�f��T
��}l�t�T������s~v�&�L��+�gZ3\Rw&�XHe�d����d����@���N����[8�g�f���������7�g�.��e�������.r�v�2	����zG(�a��I�2#"�P��
�	?�bnI>���{*��y�|��)=ky�x��J�i�](]��|):� s������69gn��c5���� �\f�tJ5��8Yydf{Y
�sN���/������.*����	7�sg�L���rS�%��m&����4�rO�i���Z�T�)�ffE�t��@�i��r����]/��d%�tYU;�u���Z�-�c*���������9�M��^5-of*�s67#sfz=���I��3wf6�9�g�g;��7w�L���:fw�	4�������O�C��+�f�.�hv����e��Bi��vG�4u�YH*���riF�d��w1�)�f���4���P�y��� �fw95���KR�n���]���JH��d������&���sjv]�j������]��V�,$wf��$���q��n�����3-u�"��2hZ�8����
����D3oV��b�hFSp�l�wW�@&�������\�	4)�4�)�2��a8TYX1M�� �J�UH�$I��������)W_���;=v^�B���n�"&��S,�1�^u�L��Ao�"�;����H���}*kd����3��}���r�fm��;k�(��6����7��cQ.y[c[�������h�VW[�f�1c�k�V-Kk�F-����uy��;����Q���P�[�}�^�#rx���U-�J����;�����_�y-8�_��*���G�}i��U�s1v:Vbo����j!��H��]j5�T�����O"��k#VMvL�JH2�T��/[A�,\3�2�P6G1#�H����E���������Z�����(w���'������������q��t|��<���m����j����\������Z*>lP#'�2%��
&6�i�	U��j~������O�i/��`J����
�p0���WK�6J9�)�{�a����9��F��4���������/?�����^�M��{����v��N��<H����~RK�)f/q��6�H�]�z9�^B����)��wD��s�����F�9y�ce`��6a���j��Mc�$��M����i�v�<�:�v��NG�C���k�@�5�:��������{h��>|���l�����M��v��
�!��Y�������o���U4���VmC�4�1��H6���S�L@�i���7����!���^��t�mL�/'��`4�����z)nP���n���U����;�18)&u�$����O;�
<L�]K����l4F��e�n�=@�!u�`rs�����;�����8���f���F.g��R�p(t
�*P �S8���o@�u�@y�>$=\������Et����	�1�������@g�p4�:K���~��$Hm����
6���-C#���j�F�m�����=Q��H�<����:�Li��HypF�@v'���`0���`8f�����h��0.�n����>k��k}�|�L�Z�
��"��O�����uXro8���c,�����l�9�y}�bc��;{�l��<?2A�_��r����������9��d�n�-���nRv���8�[�(��u�au���x�@�6s��PP#���`�Q�z�P�����P�����(Y���yV��dfAA_���'�������_R�z�wN|cx	�����,��J��c�2�-XJ��'����
Lyvx��%d5K�AA�	?�{�GJ����>�[������-�w��u�`�F{��.�m�������V�(������$��XFk��Bn�$��$t��|�y��*mH�����A��A�i�e�vQ�����=g��(V�������WN��L�!���o����v��T��d�.������cUwz
QjC��Y����1�3�A�O=�
���%��� 8��`���C>"�n-���|��:l9w�G�6��k6����i���T&M���'�a,����1�����v���T�C2������.�:-_��2-_}�*�A����&xfy���5>l�u�BO���'�TzC�A�T;|ZV�.?�Fl��Nr�J�a���I�-K����#�����AQ���0�K��,k+��*Vw+�zb�D �G)��7�R#e�����vp{`!�H�����t �.������Z[y�����C_�5q��awnZZ�Sq���������d���K�R7�����J�$��5����nDU��!�e�����;�L/A�t�e����= P�Z�9���_���8����������(��P����f,l���8��9�Y��IC��BW6|����8�(!w�I�]F}��`.�\
9BN�$��T:��O��Fc�F^����e��<�#�fr��!�S�D�5�m��U9��c�H���>���0X�!����W�Gx�C�6���H�x������To�b������,���^l�v,n16�����"i�����`��V��o������Zd�1�
N*�$�?��;&xn��B6=+f�)8�+e����C�>Jw�H�'������?k�?)��U?
��C��3��yp��n>7�M��v������������ N�(4�~xL�x�X��J����N�NPhno<���o���5v0���/S�y2�������t��#��N�
���y��;��K��g��D$�%�_�����X��"3gr�L�x�����y��O.�j��ga��5���[���1��\�V�K��P�=4P,�4j-#$8?O$����&��2Q�2�
��4S�X`���G�C�"���U�>%Wu��"X�{�\��W]��2�&/�#5��]/�LS��!6-h����VJ��gs�H���G{S����_?N<����*f�%��,/q+������%D�E����e�Si������'���x�s^��?��sQL�o%��G��_#�_!C)�_2?/�.�����(X?��gn�7�e��L/���,�
�M �8���dW���5S%�����PT�
v��
2LoRcIN�T���R�\�?J�zl�%�[�5���=�/��Fx����ynVx����6�qEP���$���r������d�P�"��r~[c6�)in�y���6�p���5�8�<�Y��j_4��B��-����Z]���|�d��R
��0#4�%(3��`B�����"�4�3���/�S��j���A���������iE�N�V�nw����P�?v#<�}'l���K"9B�mp��y��M��y�8�UW��R���v �|�n"�IY��WF\Q���@�U��y=#]j*������=�O��O�����u���;'�������O���� E�eQIi�����w
�V���^bu
�R�LI��pi$���j:O*mCT~���^U�����7��������9�!�Xwx��c)O��D�H�	z�
o��{P���m�"H�(��U�
JO3�����H3@/P��6u'��o�U\G��� �D���<���F� s��J�*8T
lm<W��|�9�/�����
0002-JSON_TABLE-v40.patch.gzapplication/gzip; name=0002-JSON_TABLE-v40.patch.gzDownload
0003-JSON_TABLE-PLAN-DEFAULT-clause-v40.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v40.patch.gzDownload
0004-JSON_TABLE-PLAN-clause-v40.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v40.patch.gzDownload
#26Pavel Stehule
pavel.stehule@gmail.com
In reply to: Nikita Glukhov (#25)
Re: SQL/JSON: JSON_TABLE

út 12. 11. 2019 v 1:13 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

Attached 40th version of the patches.

On 19.10.2019 18:31, Pavel Stehule wrote:

This patch is still pretty big - it is about 6000 lines (without any
documentation). I checked the standard - and this patch try to implement

JSON_TABLE as part of T821
Plan clause T824
Plan default clause T838.

Unfortunately for last two features there are few documentation other than
standard, and probably other databases doesn't implement these features (I
didn't find it in Oracle, MySQL, MSSQL and DB2) . Can be this patch divided
by these features? I hope so separate review and commit can increase a
chance to merge this code (or the most significant part) in this release.

It is pretty hard to do any deeper review without documentation and
without other information sources.

What do you think?

I think it is a good idea. So I have split JSON_TABLE patch into three
patches, each SQL feature. This really helped to reduce the size of the
main patch by about 40%.

super, I'lll check main patch only now - to time when it will be merged to
core

On 30.09.2019 19:09, Pavel Stehule wrote:

Regress tests fails on my comp - intel 64bit Linux, gcc 9.2.1

Unfortunately, this is still not reproducible on my computer with 64bit
Linux and gcc 9.2.1.

Maybe it is locale depending issue. My LANG is LANG=cs_CZ.UTF-8

Comments:

* +<->/* Only XMLTABLE and JSON_TABLE are supported currently */

this comment has not sense more. Can be removed. Probably long time there
will not be new format like XML or JSON

Fixed.

* there are new 600 lines to parse_clause.c, maybe this code can be placed
in new file parse_jsontable.c ? parse_clause.c is pretty long already
(json_table has very complex syntax)

Ok, the code was moved to parse_jsontable.c.

*
+<->if (list_length(ci->passing.values) > 0)
+<->{
+<-><-->ListCell   *exprlc;
+<-><-->ListCell   *namelc;
+

It's uncommon usage of list_length function. More common is just "if
(ci->passing.values) {}". Is there any reason for list_length?

Fixed.

* I tested some examples that I found on net. It works very well. Minor
issues are white chars for json type. Probably json_table should to trim
returned values, because after cutting from document, original white chars
lost sense. It is not a problem jsonb type, that reduce white chars on
input.

I did only simple tests and I didn't find any other issues than white
chars problems for json type. I'll continue in some deeper tests. Please,
prepare documentation. Without documentation there is not clean what
features are supported. I have to do blind testing.

I have added some documentation to the patches which has simply been
copied from [1], but It still needs some work.

ok

Pavel

Show quoted text

[1]
/messages/by-id/732208d3-56c3-25a4-8f08-3be1d54ad51b@postgrespro.ru

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#27Pavel Stehule
pavel.stehule@gmail.com
In reply to: Pavel Stehule (#26)
Re: SQL/JSON: JSON_TABLE

Hi

please, can you rebase 0001-SQL-JSON-functions-v40.patch. I have a problem
with patching

Pavel

#28Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Pavel Stehule (#27)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 12.11.2019 20:54, Pavel Stehule wrote:

Hi

please, can you rebase 0001-SQL-JSON-functions-v40.patch. I have a
problem with patching

Pavel

Attached 41th version of the patches rebased onto current master.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQL-JSON-functions-v41.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v41.patch.gzDownload
0002-JSON_TABLE-v41.patch.gzapplication/gzip; name=0002-JSON_TABLE-v41.patch.gzDownload
0003-JSON_TABLE-PLAN-DEFAULT-clause-v41.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v41.patch.gzDownload
0004-JSON_TABLE-PLAN-clause-v41.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v41.patch.gzDownload
��'�]0004-JSON_TABLE-PLAN-clause-v41.patch�<kS������������2�g�@vI�{��R)�,�A�,y%�����ow��4�F�IH�Ke�X�������:���v6���qo��,�3��={��9�m�3�8}{��8;�{����Xw�u:���Y�N�����3����o��6�c�~����o���(�	y4�V8?��1�e�s�`]������0������wz�N�j>���x���8�~�'�lo~`o������������3�x�<��J����q������z���wZ�3�|clg���&����|����c��`v���S�hm1�,������`�JfM�O�t-�K�n��c���k����e�5�����������l�v������1�~l�<�.���,K��~�9,�����=������-C9P��f����x�1/p���[�$��~���I�.3/5��qR��1�`/����4�����a����-�,��wv
�����(��m��3���Y��3��V��n!�Q����x4A�������q;���1�D-��b�8�5M\�G����>n�WX��Ac7��j���:l�=.�4k����LX�y���n���Q�@����ck�3��Z|�3�z`���MtM�8+��r������~g��M��������
�����f�Tt�X�4�~�g��p4:��Q�r4������$V{��`:E	��}~�ok�*������������}@���Pa����_o��Xu�������|���m�V������E�8:~}���5���N���/Ao�����i��W��WW������3x�x '?� ��Sc��~B��&&�Q"��I��v�-T�ng���B��|�C��<w��
Qvv|u}|� p��=a �G������h�?�2���9���<3�����Kv~ytrvxzr��R����v��R��A�O��v2�_i��A�B����Jw��1,��}�k��^W��U��wL�DF���B�d���U�����m�N�\�����i%��gc��@�r���&[���/Ol���1p}>fq��[���3|�1��>!���i�E����3?���}�q
�$����wOxN��@���9&,�����g7��� t!��#�m��]����N����u�m�M����b�3t(���7�����5���3���H
p�y<a�*�gt��=�d{�+�o��l!A�#�=�)*��P�@m@��b�XPi�w�Uh�5��vv~�v��k6���Z�)�x�r(.��������@�$}��dv.V�Z���/��)S��^���R����=�i�O����!.�qx�S%#��)���0EF�RKy$HK�{�	�Q���u�N1�.������%H�.K'nR�;�l��KL.��u��R�Y����w�)-�<�eH���4q6�������Kt@�XK�9!W�)L�re����S�
'B�o�<��(P5��Z�
��a��-vl;��F������!L�W���W��ry�D�y�����
��t���tN��$3�T�����R7�.����
�c�w��Vzs���E:�p�2AM�s
QCY�#�)R~WA�Q1�G�:�S���[�KJ��?uv����,
� %n�%.{2�NLkG����%�V���;�h4�U>��^LFJ�s�1HM��5D��O�^}%���B#�ZR�6D�B����?�n�Y������,l�E�P�U\���E��i�4��OKKgOe�O�JCOQA��T�(���D+c�������XJc,Z�D|������m�D�b�1* 4�1����%	c�a�}~��^��h�`��|
�*$8|���6�,��cv8V�?*��G��I$X������!���!no7zd�W���������!�|P
:!��A!�7i�k�m���R�w��n!	�Z��F��g��]�9j�r!��V-Ut V���]��
E�6�'X�+�Z��U��0yz?�5�E�Q����/��&��{1�^ z����'��������v��L��b�%V3Z��ECd���������f�������z��&@k�������~d_�r_����J�� ������;�$U���V��D��^�����{:d�j��������y|y,�| �rxv���eJ��k�����E�����'�G����@o�=����v��l�����b��`1z������	�����5��*%#,��6&a0�������w�����������������C��a�^�p`��D� 4��k#���zuxzx)�0��'���Q��0�����3�hO������>��|yE�sG<Mx$���<9�C.���$�,3��G�������,���1t�q������d4�����y���X��#X��iX����d}{�l#7����{�]�CX�]�e��)N��& �Z������6�>������9���j�J�2����DRfS���X%Kj��4����������jJq�8����`����;[&�N(HDC���8�P4	������%�/5=�������i�����x9n�����A��y���,4�~���E�����������q��5��8���l�P�l8i4PB�G������mth�8P���O�������[H��BE
���}S��d��MF���0�������0�AQg3@��on��<}�ii� �*lH��4"����@9�����8�<.�1Vf&�����������H�dJ���,����IH�x���5i�����8�e��c(S5a�IV�VUP���[��
����B	�x�`B����/�0G"R�7tG����kX���X@�#�lTDze��.�^�2,�y�N�e��A�~�^gI�2��e��o$�`�\]_�������$�(~���0���7X�%���R�jC�~�����D�����X|�;����x
�5����`��0������O�>Q��%6��4)k:�,b��l���V`O,�^f�2��@�3n�t�5�OL)�����y�Op��B��+ax����Z���w��u������h]&P�C��,�J���������Y�(�O����4$|��2��9MR����'|ks���Z���5�/���L�:�����&>Q�b�>�=(�������9����!A�DJf������Ry�G���Q�4
#�[�z��|L�����#�!�[�d{Ar��]�_ve�emb ���@�i��[���<��;����$��T;d!���
v�37����
��yx/��5�!�7s��a����.��"��yc>^��Q
�8���#���`��/A���`�\H�y����e�B�X2��~�������
��!�2��P�Q��'�@��L�)�o�S�n��gfGx��3�to�����{����z	�.)�D����B�L'��L�
Y�,m\�GK�H�R;C���T�1��W�z��~�sw%6�%h�����H���_�o�=�e��I�K�lsOr(��=��I����B���5�J��."����k��o]���3D�ej�R��k��(`H����"WC�"m*�6��U���+$� �J$7��Hj��<I�������K��e�"���k^���g����SI�����XV�MOO�zV�:8%���x��B��J��%���PS1�(��iq�������{��!�7(������w��K�H *l�^�BG�8�� ���2�2@�u�������
�7���y�������)���[A ��Y�"�iQ�����&�}_�>���]X���:y{qz\��]�yN��f���.���$3������$�0����'���E��9�T��>Db
���k?jtI���0:N|
����I}4��&dEA$	�-�4#��W�x����]�D�O_��b�b������������/lv�"���=H�8��o,k�=�j�<�3+�`���G0t3W�r��2h$��=m�=}�(w��@`�r�"�o��M�3���<T��]�}(��kl������h���Z�����v��$��J�EP��z��������P&�Y�g�>^X�O&� L{�X���~�~�)?S��N����w��r��9�k4�Ol�o`����H������.���7�.\q[��F�	j��XNO/d�8
������1�M��|z}?sa�������`xc�U���e�ay(���j��q��\�U�����%N
�0)gT��
��kP��W�������<���H$b@�9��w��w�=��(U!���������f���P�}����o0o��Q\��������h�he�^���#��%����-���ZU"9;c
�����N��	g�=Q�~�`)_8�VA�Cr����/�1oE�-�������k'B*u�����B=���'Z8<4�����=���z�6/Sz9,��������xR��
�����{�������u���^2� �g �<�K�U7*��h�/��;����MP:_9���	�3K`���5"\�Hd��)�$=c Hl�%�����x@�h�7|e}	��dF\x>P�;������N��������Hk#����p0�3u����1`C�9#��~P��"����!����/m#��Qi���a��@[��`w"qX�?�D��(9s�-'_F�&����{m+�X#�!.q��<j������q/��_^�C}���w��Ss)����f��
�LO���?�}�xqCwR���{��'�>���$��dA��T�����)��es� �?�����|�%1QyG�]���A��c�QX2p��M����>a�wr��;���0.0�����'��9���i�����o�lx��I�%��~vr��$V>Iw��R�L���"5�s�_�@H����BP�6XJ������]��W�Y��Z/$��s�9_��
�.��_L9�,�"�A�����A���+<T�zwv}�?C����itS]���i�R��V�("4k=M�����x�;��e��Dd���5(�F�.�x]�J�xt0"j�W���0�;��|�BnD��������(�_�t�j�Do��ePU��b�3�e�4M'�2��v�o�A�'�zR9�!Z�zt�A�^u}�.�{7:�~�t����������|��C2�F_�'i�Cb�(���������09��hb�J\�}f�I�[	@���~&D��.Yi y��~�J��,�9�B�#�G\�����U�hg$�|��-�����N�^������)}����=.:f����%���I��L�H�i�L�,�~_��l&����%���@��!K�is�.o�[��zZ i�b�\����
��R�������:���~���v��T��
V����:��T�������A���d���ml�k�D��S�O\�����.=x�J}	��9u��	i^r���O�"S��p�5C�nQ��hr���_�+R
���L��������[��c`�3�6��).��<����iG�+��� tmq\AI=,��Q.q���������MgM����=��atO��k��F|�L��m&A�)Q��y�X94	�@���V����������f�K�d��c�������`�H19����6��)�^q�Y����Z��[^���z��Tj�S���n�E5��HS�}���l�,�_�,��(&*-��i#���n��y_��(�}���y�k��&X\��dk����w��<�}�P
&/�T"���`��&X��L��G!s�V�NbY�2�'"�}�J"��u��v�F�������l��*����,�B�&bp��3�����%��4���2�[��K��>BY���$�(4�j��?l,>v��)%��e/��/�7I2��3�Y��w`�2���T��L�'W�O��V��#a��f����fe>�Hg�Ur��oT�Ic��z9��E�������Wdh��c ��X���kvH-�������0y�7�#h:��u�����5U��2�)��+w@Z8�|Xv�kL�H0f��.�/^��8w��B)�#�Q��D�#�&�VM��f�/	�����I����[����J�5DE����2�G�s�G���nf����2/6��p�����7m� �5���%��k�Z�����o�)N������4�����h�c{-��99^6E9tdJ)������*�@��M��D}l���T
@���X�����w�&�' ��<>pL;8Z-���y�H��z�������W�
@X�2K��2K��1K�z���!�(mNl0 ����z!Ap�I�^G����/_����K_�\��}c��'��l�����Tj���VU3uP�oT����O��'������=�0�����~�!�v�a<�h��T�3+%�
W���K������T}_����2@*Nt�R�1l;�<��L��jcL�k�Z�F�l[Z�DRTVk�j�F��V�~L�����{?y/	�\��L��>��Z���h��#A�'�l�RT=����I�y������aO��(��%\~��{�E�CR��!b�7�����v����!��\���Pw�<S]f�op����|���<����/��%�%)�wsR��<��nFaj�9�����y��w)�v$����������P����<w���7�&'^�[�����)��LU]�����|t�;:��������-���]W���}+vD���m���������Wl2�2��s�F?0t@@�?���������c~q�	V�5$gY�����F�J_`C����K��'����Y-��\����'��%�4U�y>����d�	~���L�Lr�$�Y�o�!�~`����%��b�,_z�zMY�fb��\�9�Z�(M�hI���RO���T�i�"0�Z:�Q��LZ4"��'��tMN����"���h����^���`0��T��o��fF� \�;��h��:���gid��a�:3����Ja��$�����k�����S���i]60��aW�p��d��W�[��������M3$����c����q�_ /�#�F��uN��n4�Q��`/%�`����^��������
o��7�w�m���0��3_<��3��L�V���&"Z��/r�U)�WdS��?��).37��\E�4�G����Lt�@(���&K�oO�MF{*`,�f�+@��7)f?*}�e�
e$I�S������I.��]�Y2���b8�0
�S�}����RJs�*�b[F��K4W�.<����cpW������2\�U��r�hvP�v�N��Y��[������n��m$A���?�z��(�(�.���i���5-1�%���\4��}2�!�x��=G�k��=��"+��=�*����zxe�P='@��)�a���	{�a�V��V*wE������L������Su,"K���Gau)����"�#��}��*��Y
W��j�p'��jMWIY;����:���p�#���Z���Z*W3!���Mq�64?����o	2$�-��T\*H����*��d`�t=���3���p�&zD��!A�}��n� 9���`j�><	�N�2��3i)��.!V!Sf�$K��^QCd�y�R��W����fV�$�w�l3�8,qT���dNM><3�V��
��������F��ik��m�pj~u-w���I4�v��<������^={�70�/�/����e(�U��
��k�/����OP��a'���xuF�(���/!]����1�#��#}��4������������u��j/�����	�����NN�������(��K�dA��$�F�@i��? �K!���$HgZN9��0P��R�*��]���P���*u3�j�����_��d)�*s�;�=��R�`�9��������/�6�)8�
��X����m��f��^����v?:������<��2Q0����^q�9({���6E ���}+X@(�\��CF����E���=�L�Pq�t�	k�����2��f���]g��;�s�0�����b�C���#���PzQ��/�?�k4�
1V$A���G������Q� ��x|Ik��:e6�5?0�9���~�'����~)�}1����6�Q�	�w��|������Zb�p� ����H�%e{X�|���X5��o2�%��#��K��}e�iWC�Uk�F��K�<���]/�J��KV
��������ojPs�*2�yh4���]�pMrL��;��6>&��l��(��'��;;�8+0����9u���j�Nr<���GB:\!!�� 8q�[J��������J _���"�4��U����J�d��B4�e������4���0�[>h���/�����/�)0�ZJry�J Tb7��y.����'q���(~LF�Ij�J�,CP�� "�$�4��$��mI�!�N�&���^�I�_�vO�Kr
+_���%l��mET'vA;Z��� �$%���)A���0by"�~r��O�O�l��{������&�W��r!�g�����{��������u���1��M���(>�z���6����d����	�#�����1��H������������=?8>>z�_,����-�T�D��]_z�Y_�%�h�tE��t*A����iXP��r�p�_Q@@aLh$Bw���O�dd$"�k���yz_�W���GQ�KB]���lz���a|="D��p�J<_#�]�����#�p�X@of����6���r��X�O��(��S>���%�KF��vSX�z�tq�]����Z��~x���'���U�[��..`sU��D��x�>���(9:M���TR��5{�vg��������=�Xd�)_����S���O�]^����W'{t=�=���������:->�����l���
�)D}�-�����d���cC8e$d���N��e�o�}�5�~�f1v8�K��a��p�5�$2i�"eR��]��V�����6O�6U0]yQ����^eg���M~�[���r��^�-/����+f��l�������q�$���	�z���R�7(��`��������t��"�������b����!���/����!{yt�#������\��+��1�J�w�iM0�K�az�������Z|�}LoG,��/��O��Z��9�Dx|�`0lf��V������tdn�F�i��0���7���TU�t���y�
`����rh'�������2sg���{R
��i�=����^���Vb��K3���/�G�V,���l)O�T�/������	J0&�aE���@�N� C� �z��e`�Y�����0��Sk7]���{�M���#�p]����D&�����yGG������������1{��M����_���e������p�<�����&qq�=y`�������gh�l������)�=�q��<|�G�����'��#<7�z�|v=������>p3#�2��+F�������X-��Y�l��:�~?������ffB��aV�n6��|������l�o&�	q6G&%����6��xx~���S,���s���9v���19�b��;zz�����M���IC��v�j�l����%<F���h>�����?�\��$����|�n�f5E�O�L�-V�*�z��(/��4�0��>����Ef�B+����p-���c.�Y������z=��v�R\����-�x�jE#��u����2y����8������q�XhP_qH���#kC���.�������r�Z�8�C�p�x�q��:^��Cp��:�hP���B^��hnC��|��}�V.�����������0���`�����>?eg��9�-q2a����x�:EHM\��v}��C�����</�W�����;v5��zr�{���
���Cg����=��V�Uo5y�H����j�����!�3Z��{�w���x,MJ;V%�"���7)��5u:\Lz+���k%z����v����3G���#�L��k���t2�O��_/p��m��t�z�`TV��3
^�D�?j���?#�K2t�����?zz�SV�^z{]^	��b
8����M����9���;#��1���l"�>������m�s������%}he����^��F���]�,3:K��f�_��^3��kg��4)M��N	�#��}F?+���,��d��R]%{Jw�d���*/j�r�s��k���(h��^�����Ko�d���p��W2I�E&P����j<�����H�o������?�\u"���R��H����jCy��[��]!t����y��:��n9�y����f��'��IX�yU�z7�c���;�����a�U�������nNyE�x�Z����-�p{����2��7��
��
�
�8X��`�]M��#o]U����^/�k��]���_\x�c�]r�`��u�I�
�����IC7_��uU�����_�V�����@������!X��!��9s���<�����_Wd�M!���.�����m�<q��X�S�^A��:h��{����rV�����y�Zc�q<�&hqyr���L���G��g�hUL�����/N���gf>a��t���w�O����z��������]axWky7G�B4o�d�L��)�Mb�������-��	S!�j��(>��j��Z>����_Bn����6��c�Im,V��B[/zwd�;2��aPT-t6.�<��QR���	�����k�!u�����\�H��w��"E�g:K�k�F�,��D`3"@@��65D>i~I*!(H 5t#O\Mb�".5���Y��s�a5�O[TRY�K�R�}$���hk!]
R/
,�a�<��H��5��XJ��'�<�SL��|���\�$x.`'� �6��������0�������@|=T�JR����3)2O*��b9IR�N�.�:q�r8"a���r?49���l��������P���-=%P�.�����*N�W�� S��]b��7��M�nJ��)�k��Q���^0hF����+�K	�����av�.9�n���-�Xn���6[���M�V���B�w�QWQhR�C�PV�Ug�����F��J\C�e�����.K�RF���@����+��Jh����j$reSXb[��KalWV�����Wb��c�,(k�pk�����h����/���4M�e5Y�B.��f��.��:S7��"M����0�
�����-�G�l@��O���+������O?��?���&�)�a����^��pL��s�!I���4�R����x�o|�_TBb�7x�����5^U�^W1wu3��w�,+��_���+*��HJ��d�ZdZ�o�@����T����0z{t�V����2�����
},Fy:�a��
���.<���{���u��O,N�>��C��������������I�
�/F�,��/�8��E�A����.�`ZcP�f��8{�_z�:9�A�2���:ef�KWT�3�	e��0{P��0���[�]k���A���/�1��0�����L��,�<���2;K�����^!B(g�����5�CVn
^��%���_�w�3�Q�J(�.!�/�r/s[p��Q��v?G�r8���@��������0;�G7p��kf�:���R��� �cU�p�Z�;�`�za�����V��aw �z�aw �����]Uo��^<��^={�=�1����7�<������=��q��
]]7w�C� z����*cby u7P�|�8$�mDR�;����RH���P�H=��H���@��K}�����z�:�z��:8�L��	����z���S������	P=��P=�(Q�� ��/n{!������Uw�}�����Xu��?��c�Vw�����Kq���;l�	�-b�������%�zW�]]%���h�WWs��?�#����^>��V�C����S�X�A
^w�������A��n�P�����g�i������b)}�H�N��
��G_<��=�r���	q�H�w���Ns�Gv��+��;=��z��<"q5Rx���NY�WV�������
���N����[�6w���������c�C4w���\��!�;Ds�h���C4��z���	68�mC��(�q/<��g�v�����skI9������
V���W�W�j�0=rU�l������,�8���;�eb��
����t�.��^T�������|�^��m2�KD�~����:������0�QHpQ�iF�B�����_e��[����YX�=��`�Q�� ��c��W��e��� {�Q��^�\���
��:�&Wn���{��.h��]{���lqHyqu�����rG��#��n<�h��8eG��F;z�5��sc����u���(�e��B���2�]���"���E���~����� D�f����J|W��*�#��Q��EW�]i������T#Y�4��6p���	�+�X���8���q��(�5���v�[$k�!�:[��z��C��v��.��������XS`��k���I��[�<��j�jZSt��kT�I���i�����F��ByV�a�*\�a��������m5{������eq�JM��r/�c����?��?���ma�?��S���c��ikt1�����Xz|��a�����O���*�4?�o���Y�M��U��S_}y��_�e�,���u��-�����(�y�v<�����~���~����"K�v��9�/G�����Oj�w	�U���~��[��o�o�����X����w�����=
����(��
���
��x	�Z��b�����v�{�;����q�����kvFw]�7������m7���h{;����;�Hw���[���hd4<�:��w����h��^D���^��E��[���t4w�����q��\��V�J���r7����
����w������x����Qp7��	�]d������m�<��|qq>{t�|���G�O�c��Y�|�UU�0��y����9k�����:��������(^��w:���������'0�#O�+�j��X��\L����\����q:zq:�m���wj�'�����:�G�L
���|2}�UP��/cz��h7h������M�����
#29Pavel Stehule
pavel.stehule@gmail.com
In reply to: Nikita Glukhov (#28)
Re: SQL/JSON: JSON_TABLE

Hi

út 12. 11. 2019 v 22:51 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

On 12.11.2019 20:54, Pavel Stehule wrote:

Hi

please, can you rebase 0001-SQL-JSON-functions-v40.patch. I have a
problem with patching

Pavel

Attached 41th version of the patches rebased onto current master.

I can say so broken regress tests has related to locales

with czech locale LANG=cs_CZ.UTF8 following two tests fails

json_sqljson ... FAILED 148 ms
jsonb_sqljson ... FAILED 3791 ms

The problem is in comparison digits and chars. the result is locale depend.

postgres=# select '10' > 'a' collate "C";
┌──────────┐
│ ?column? │
╞══════════╡
│ f │
└──────────┘
(1 row)

postgres=# select '10' > 'a' collate "cs_CZ";
┌──────────┐
│ ?column? │
╞══════════╡
│ t │
└──────────┘
(1 row)
postgres=# select '10' > 'a' collate "en_US";
┌──────────┐
│ ?column? │
╞══════════╡
│ f │
└──────────┘
(1 row)

Regards

Pavel

Show quoted text

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#30Pavel Stehule
pavel.stehule@gmail.com
In reply to: Nikita Glukhov (#28)
Re: SQL/JSON: JSON_TABLE

Hi

út 12. 11. 2019 v 22:51 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

On 12.11.2019 20:54, Pavel Stehule wrote:

Hi

please, can you rebase 0001-SQL-JSON-functions-v40.patch. I have a
problem with patching

Pavel

Attached 41th version of the patches rebased onto current master.

I testing functionality - randomly testing some examples that I found on
internet.

I found:

a) Oracle & MySQL (Oracle) supports EXISTS clause, this implementation not.
I think should be useful support this clause too.

SELECT * FROM JSON_TABLE('...', '...' COLUMNS x INT EXISTS PATH ...

There is a question how to map boolean result to other data types.

b) When searched value is not scalar, then it returns null. This behave can
be suppressed by clause FORMAT Json. I found a different behave, and maybe
I found a bug. On MySQL this clause is by default for JSON values (what has
sense).

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON EMPTY
)
) AS tt;

It returns null, although it should to return [1,2].

There is another bug maybe. Although there is DEFAULT clause. It returns
NULL.

I got correct result when I used FORMAT JSON clause. I think it should be
default behave for json and jsonb columns.

Another question - when I used FORMAT JSON clause, then I got syntax error
on DEFAULT keyword .. . Is it correct? Why I cannot to use together FORMAT
JSON and DEFAULT clauses?

Note - this behave is not described in documentation.

Regards

Pavel

Show quoted text

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#31Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Pavel Stehule (#30)
Re: SQL/JSON: JSON_TABLE

On 17.11.2019 13:35, Pavel Stehule wrote:

Hi

út 12. 11. 2019 v 22:51 odesílatel Nikita Glukhov
<n.gluhov@postgrespro.ru <mailto:n.gluhov@postgrespro.ru>> napsal:

On 12.11.2019 20:54, Pavel Stehule wrote:

Hi

please, can you rebase 0001-SQL-JSON-functions-v40.patch. I have a
problem with patching

Pavel

Attached 41th version of the patches rebased onto current master.

I testing functionality - randomly testing some examples that I found
on internet.

Thank you for testing JSON_TABLE.

I found:
a) Oracle & MySQL (Oracle) supports EXISTS clause, this implementation not.
I think should be useful support this clause too.
SELECT * FROM JSON_TABLE('...', '...' COLUMNS x INT EXISTS PATH ...

EXISTS PATH clause can be emulated with jsonpath EXISTS() predicate:

=# SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a bool PATH 'exists($.a)',
b bool PATH 'exists($.b)'
));
a | b
---+---
t | f
(1 row)

But this works as expected only in lax mode. In strict mode EXISTS() returns
Unknown that transformed into SQL NULL:

=# SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a bool PATH 'strict exists($.a)',
b bool PATH 'strict exists($.b)'
));
a | b
---+---
t |
(1 row)

There is no easy way to return false without external COALESCE(),
DEFAULT false ON ERROR also does not help.

So, I think it's worth to add EXISTS PATH clause to our implementation.

There is a question how to map boolean result to other data types.

Now, boolean result can be used in JSON_TABLE columns of bool, int4, text,
json[b], and other types which have CAST from bool:

SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a int PATH 'exists($.a)',
b text PATH 'exists($.b)'
));
a | b
---+-------
1 | false
(1 row)

b) When searched value is not scalar, then it returns null. This behave can be
suppressed by clause FORMAT Json. I found a different behave, and maybe I found
a bug. On MySQL this clause is by default for JSON values (what has sense).
SELECT *
FROM
      JSON_TABLE(
        '[{"a":[1,2]}]',
        '$[*]'
        COLUMNS(
         aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON EMPTY
        )
      ) AS tt;
It returns null, although it should to return [1,2].

Yes, regular (non-formatted) JSON_TABLE columns can accept only scalar values.
Otherwise an error is thrown, which can be caught by ON ERROR clause. This
behavior is specified by the standard.

FORMAT JSON is not implicitly added for json[b] columns now. The current SQL
standard does not have any json data types, so I think we can add implicit
FORMAT JSON for json[b] typed-columns. But I'm a bit afraid that different
behavior can be standardized after introduction of json data types in SQL.

There is another bug maybe. Although there is DEFAULT clause. It returns NULL.

ON ERROR should be used if "not a scalar" error needs to be caught:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON ERROR
)
) AS tt;

aj
------------
{"x": 333}
(1 row)

ON EMPTY catches only empty-result case (for example, non-existent path in
lax mode):

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.foo' DEFAULT '{"x": 333}' ON EMPTY
)
) AS tt;
aj
------------
{"x": 333}
(1 row)

I got correct result when I used FORMAT JSON clause.
I think it should be default behave for json and jsonb columns.

I agree that FORMAT JSON could be implicit for json[b] columns. But I think
there could be one minor problem if we want to verify that returned value is
scalar.

Without FORMAT JSON this is verified by the underlying JSON_VALUE expression:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS (
aj JSON PATH 'lax $.a' ERROR ON ERROR
)
) AS tt;
ERROR: JSON path expression in JSON_VALUE should return singleton scalar item

(This error message with the reference to implicit JSON_VALUE needs to be fixed.)

But with FORMAT JSON we need to construct complex jsonpath with a filter and
override ON EMPTY behavior:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS (
aj JSON FORMAT JSON
-- strict mode is mandatory to prevent array unwrapping
PATH 'strict $.a ? (@.type() != "array" && @.type() != "object")'
ERROR ON EMPTY ERROR ON ERROR
)
) AS tt;
ERROR: no SQL/JSON item

Another question - when I used FORMAT JSON clause, then I got syntax error
on DEFAULT keyword .. . Is it correct?

Why I cannot to use together FORMAT JSON and DEFAULT clauses?

JSON_TABLE columns with FORMAT JSON, like JSON_QUERY, can have only
ERROR, NULL, EMPTY ARRAY, EMPTY OBJECT behaviors.

This syntax is specified in the SQL standard:

<JSON table formatted column definition> ::=
<column name> <data type> FORMAT <JSON representation>
[ PATH <JSON table column path specification> ]
[ <JSON table formatted column wrapper behavior> WRAPPER ]
[ <JSON table formatted column quotes behavior> QUOTES [ ON SCALAR STRING ] ]
[ <JSON table formatted column empty behavior> ON EMPTY ]
[ <JSON table formatted column error behavior> ON ERROR ]

<JSON table formatted column empty behavior> ::=
ERROR
| NULL
| EMPTY ARRAY
| EMPTY OBJECT

<JSON table formatted column error behavior> ::=
ERROR
| NULL
| EMPTY ARRAY
| EMPTY OBJECT

But I also think that DEFAULT clause could be very useful in JSON_QUERY and
formatted JSON_TABLE columns.

Note - this behave is not described in documentation.

There are references to JSON_QUERY and JSON_VALUE behavior in the definitions
of JSON_TABLE columns, but their behavior still seems to be unclear. This
needs to be fixed.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#32Pavel Stehule
pavel.stehule@gmail.com
In reply to: Nikita Glukhov (#31)
Re: SQL/JSON: JSON_TABLE

čt 21. 11. 2019 v 17:31 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

On 17.11.2019 13:35, Pavel Stehule wrote:

Hi

út 12. 11. 2019 v 22:51 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

On 12.11.2019 20:54, Pavel Stehule wrote:

Hi

please, can you rebase 0001-SQL-JSON-functions-v40.patch. I have a
problem with patching

Pavel

Attached 41th version of the patches rebased onto current master.

I testing functionality - randomly testing some examples that I found on
internet.

Thank you for testing JSON_TABLE.

I found:

a) Oracle & MySQL (Oracle) supports EXISTS clause, this implementation not.
I think should be useful support this clause too.

SELECT * FROM JSON_TABLE('...', '...' COLUMNS x INT EXISTS PATH ...

EXISTS PATH clause can be emulated with jsonpath EXISTS() predicate:

=# SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a bool PATH 'exists($.a)',
b bool PATH 'exists($.b)'
));
a | b
---+---
t | f
(1 row)

But this works as expected only in lax mode. In strict mode EXISTS() returns
Unknown that transformed into SQL NULL:

=# SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a bool PATH 'strict exists($.a)',
b bool PATH 'strict exists($.b)'
));
a | b
---+---
t |
(1 row)

There is no easy way to return false without external COALESCE(),
DEFAULT false ON ERROR also does not help.

So, I think it's worth to add EXISTS PATH clause to our implementation.

There is a question how to map boolean result to other data types.

Now, boolean result can be used in JSON_TABLE columns of bool, int4, text,
json[b], and other types which have CAST from bool:

SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a int PATH 'exists($.a)',
b text PATH 'exists($.b)'
));
a | b
---+-------
1 | false
(1 row)

b) When searched value is not scalar, then it returns null. This behave can be
suppressed by clause FORMAT Json. I found a different behave, and maybe I found
a bug. On MySQL this clause is by default for JSON values (what has sense).

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON EMPTY
)
) AS tt;

It returns null, although it should to return [1,2].

Yes, regular (non-formatted) JSON_TABLE columns can accept only scalar values.
Otherwise an error is thrown, which can be caught by ON ERROR clause. This
behavior is specified by the standard.

FORMAT JSON is not implicitly added for json[b] columns now. The current SQL
standard does not have any json data types, so I think we can add implicit
FORMAT JSON for json[b] typed-columns. But I'm a bit afraid that different
behavior can be standardized after introduction of json data types in SQL.

There is another bug maybe. Although there is DEFAULT clause. It returns NULL.

ON ERROR should be used if "not a scalar" error needs to be caught:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON ERROR
)
) AS tt;

aj
------------
{"x": 333}
(1 row)

ON EMPTY catches only empty-result case (for example, non-existent path in
lax mode):

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.foo' DEFAULT '{"x": 333}' ON EMPTY
)
) AS tt;
aj
------------
{"x": 333}
(1 row)

I got correct result when I used FORMAT JSON clause.
I think it should be default behave for json and jsonb columns.

I agree that FORMAT JSON could be implicit for json[b] columns. But I think
there could be one minor problem if we want to verify that returned value is
scalar.

Without FORMAT JSON this is verified by the underlying JSON_VALUE expression:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS (
aj JSON PATH 'lax $.a' ERROR ON ERROR
)
) AS tt;
ERROR: JSON path expression in JSON_VALUE should return singleton scalar item

(This error message with the reference to implicit JSON_VALUE needs to be fixed.)

But with FORMAT JSON we need to construct complex jsonpath with a filter and
override ON EMPTY behavior:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS (
aj JSON FORMAT JSON
-- strict mode is mandatory to prevent array unwrapping
PATH 'strict $.a ? (@.type() != "array" && @.type() != "object")'
ERROR ON EMPTY ERROR ON ERROR
)
) AS tt;
ERROR: no SQL/JSON item

please, check the behave of other databases. I think so good conformance

with other RDBMS is important. More this method for checking if value is
object or not looks little bit scary.

maybe we can implement some functions like JSON_IS_OBJECT(),
JSON_IS_ARRAY(), JSON_IS_VALUE()?

More - we have this functionality already

ostgres=# select json_typeof('[10,20]');
┌─────────────┐
│ json_typeof │
╞═════════════╡
│ array │
└─────────────┘
(1 row)

Another question - when I used FORMAT JSON clause, then I got syntax error

Show quoted text

on DEFAULT keyword .. . Is it correct?

Why I cannot to use together FORMAT JSON and DEFAULT clauses?

JSON_TABLE columns with FORMAT JSON, like JSON_QUERY, can have only
ERROR, NULL, EMPTY ARRAY, EMPTY OBJECT behaviors.

This syntax is specified in the SQL standard:

<JSON table formatted column definition> ::=
<column name> <data type> FORMAT <JSON representation>
[ PATH <JSON table column path specification> ]
[ <JSON table formatted column wrapper behavior> WRAPPER ]
[ <JSON table formatted column quotes behavior> QUOTES [ ON SCALAR STRING ] ]
[ <JSON table formatted column empty behavior> ON EMPTY ]
[ <JSON table formatted column error behavior> ON ERROR ]

<JSON table formatted column empty behavior> ::=
ERROR
| NULL
| EMPTY ARRAY
| EMPTY OBJECT

<JSON table formatted column error behavior> ::=
ERROR
| NULL
| EMPTY ARRAY
| EMPTY OBJECT

But I also think that DEFAULT clause could be very useful in JSON_QUERY and
formatted JSON_TABLE columns.

Note - this behave is not described in documentation.

There are references to JSON_QUERY and JSON_VALUE behavior in the definitions
of JSON_TABLE columns, but their behavior still seems to be unclear. This
needs to be fixed.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#33Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Pavel Stehule (#32)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 42th version of the patches rebased onto current master.

Changes from the previous version:
* added EXISTS PATH columns
* added DEFAULT clause for FORMAT JSON columns
* added implicit FORMAT JSON for columns of json[b], array and composite types

On 21.11.2019 19:51, Pavel Stehule wrote:

čt 21. 11. 2019 v 17:31 odesílatel Nikita Glukhov
<n.gluhov@postgrespro.ru <mailto:n.gluhov@postgrespro.ru>> napsal:

On 17.11.2019 13:35, Pavel Stehule wrote:

I found:

a) Oracle & MySQL (Oracle) supports EXISTS clause, this implementation not.
I think should be useful support this clause too.
SELECT * FROM JSON_TABLE('...', '...' COLUMNS x INT EXISTS PATH ...

EXISTS PATH clause can be emulated with jsonpath EXISTS() predicate:

=# SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a bool PATH 'exists($.a)',
b bool PATH 'exists($.b)'
));
a | b
---+---
t | f
(1 row)

But this works as expected only in lax mode. In strict mode EXISTS() returns
Unknown that transformed into SQL NULL:

=# SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a bool PATH 'strict exists($.a)',
b bool PATH 'strict exists($.b)'
));
a | b
---+---
t |
(1 row)

There is no easy way to return false without external COALESCE(),
DEFAULT false ON ERROR also does not help.

So, I think it's worth to add EXISTS PATH clause to our implementation.

There is a question how to map boolean result to other data types.

Now, boolean result can be used in JSON_TABLE columns of bool, int4, text,
json[b], and other types which have CAST from bool:

SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a int PATH 'exists($.a)',
b text PATH 'exists($.b)'
));
a | b
---+-------
1 | false
(1 row)

EXISTS PATH columns were added. Only column types having CASTS
from boolean type are accepted.

Example:

SELECT *
FROM JSON_TABLE(
'{"foo": "bar"}', '$'
COLUMNS (
foo_exists boolean EXISTS PATH '$.foo',
foo int EXISTS,
err text EXISTS PATH '$ / 0' TRUE ON ERROR
)
);

foo_exists | foo | err
------------+-----+------
t | 1 | true
(1 row)

b) When searched value is not scalar, then it returns null. This behave can be
suppressed by clause FORMAT Json. I found a different behave, and maybe I found
a bug. On MySQL this clause is by default for JSON values (what has sense).
SELECT *
FROM
      JSON_TABLE(
        '[{"a":[1,2]}]',
        '$[*]'
        COLUMNS(
         aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON EMPTY
        )
      ) AS tt;
It returns null, although it should to return [1,2].

Yes, regular (non-formatted) JSON_TABLE columns can accept only scalar values.
Otherwise an error is thrown, which can be caught by ON ERROR clause. This
behavior is specified by the standard.

FORMAT JSON is not implicitly added for json[b] columns now. The current SQL
standard does not have any json data types, so I think we can add implicit
FORMAT JSON for json[b] typed-columns. But I'm a bit afraid that different
behavior can be standardized after introduction of json data types in SQL.

There is another bug maybe. Although there is DEFAULT clause. It returns NULL.

ON ERROR should be used if "not a scalar" error needs to be caught:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON ERROR
)
) AS tt;

aj
------------
{"x": 333}
(1 row)

ON EMPTY catches only empty-result case (for example, non-existent path in
lax mode):

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.foo' DEFAULT '{"x": 333}' ON EMPTY
)
) AS tt;
aj
------------
{"x": 333}
(1 row)

I got correct result when I used FORMAT JSON clause.
I think it should be default behave for json and jsonb columns.

I agree that FORMAT JSON could be implicit for json[b] columns. But I think
there could be one minor problem if we want to verify that returned value is
scalar.

Without FORMAT JSON this is verified by the underlying JSON_VALUE expression:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS (
aj JSON PATH 'lax $.a' ERROR ON ERROR
)
) AS tt;
ERROR: JSON path expression in JSON_VALUE should return singleton scalar item

(This error message with the reference to implicit JSON_VALUE needs to be fixed.)

But with FORMAT JSON we need to construct complex jsonpath with a filter and
override ON EMPTY behavior:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS (
aj JSON FORMAT JSON
-- strict mode is mandatory to prevent array unwrapping
PATH 'strict $.a ? (@.type() != "array" && @.type() != "object")'
ERROR ON EMPTY ERROR ON ERROR
)
) AS tt;
ERROR: no SQL/JSON item

please, check the behave of other databases. I think so good
conformance with other RDBMS is important. More this method for
checking if value is object or not looks little bit scary.

maybe we can implement some functions like JSON_IS_OBJECT(),
JSON_IS_ARRAY(), JSON_IS_VALUE()?
More - we have this functionality already

ostgres=# select json_typeof('[10,20]');
┌─────────────┐
│ json_typeof │
╞═════════════╡
│ array       │
└─────────────┘
(1 row)

Implicit FORMAT JSON is used for columns of json[b], array and composite types now.
The behavior is similar to behavior of json_populate_record().

Example:

CREATE TYPE test_record AS (foo text[], bar int);

SELECT *
FROM JSON_TABLE(
'{"foo": ["bar", 123, null]}', '$'
COLUMNS (
js json PATH '$',
jsonb_arr jsonb[] PATH '$.foo',
text_arr text[] PATH '$.foo',
int_arr int[] PATH '$.foo' DEFAULT '{}' ON ERROR,
rec test_record PATH '$'
)
);
js | jsonb_arr | text_arr | int_arr | rec
-----------------------------+----------------------+----------------+---------+---------------------
{"foo": ["bar", 123, null]} | {"\"bar\"",123,NULL} | {bar,123,NULL} | {} | ("{bar,123,NULL}",)
(1 row)

Another question - when I used FORMAT JSON clause, then I got syntax error
on DEFAULT keyword .. . Is it correct?

Why I cannot to use together FORMAT JSON and DEFAULT clauses?

JSON_TABLE columns with FORMAT JSON, like JSON_QUERY, can have only
ERROR, NULL, EMPTY ARRAY, EMPTY OBJECT behaviors.

This syntax is specified in the SQL standard:

<JSON table formatted column definition> ::=
<column name> <data type> FORMAT <JSON representation>
[ PATH <JSON table column path specification> ]
[ <JSON table formatted column wrapper behavior> WRAPPER ]
[ <JSON table formatted column quotes behavior> QUOTES [ ON SCALAR STRING ] ]
[ <JSON table formatted column empty behavior> ON EMPTY ]
[ <JSON table formatted column error behavior> ON ERROR ]

<JSON table formatted column empty behavior> ::=
ERROR
| NULL
| EMPTY ARRAY
| EMPTY OBJECT

<JSON table formatted column error behavior> ::=
ERROR
| NULL
| EMPTY ARRAY
| EMPTY OBJECT

But I also think that DEFAULT clause could be very useful in JSON_QUERY and
formatted JSON_TABLE columns.

DEFAULT clause was enabled in JSON_QUERY() and formatted JSON_TABLE columns:

SELECT *
FROM JSON_TABLE(
'{"foo": "bar"}', '$'
COLUMNS (
baz json FORMAT JSON DEFAULT '"empty"' ON EMPTY
)
);
baz
---------
"empty"
(1 row)

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQL-JSON-functions-v42.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v42.patch.gzDownload
�E�^0001-SQL-JSON-functions-v42.patch�<iSG��5���o�}3�F��%@��p(5�5C���q l�������{,��x��h��2++�������Y_���vgo$�?�=c22;����b���Q�����.����������N���<4�����������{�������f��������S�}v�k��K��N���z��=Vmu[��e8y/�`��;?�:���������W���g�l:F`��_����
3\'��Is1����'�����
Y5��O���)��,�� $�*lj�F�������D��)�����~*�L�q#�i��������@���w~���N�b�P���GN>,��hDX�,�}��[�0l8b�d����m���<�E~b�=	��������G&�E\G������J`�{��Rh�V'�-	:�7b��l�_L1�~����b7�w%��e{��K)nwG9PwXs��5<�n���Y��YV3b�0���a�������,Y���y|��/:���Z��������6�p��Du�dk	Y����ETf�)4�f"�!B:{�(�<�� �\�����}�)S�v������2L�2}��$�C������mKA��A�����y�t0\t��,���=;Y��)��@��c�|�`
@}�;
;
��-;������G}#�%��vh�(v@��3g3��Y��H] ���8D�,�jH�FJ������"P�d7MA��H��Bf�~.�����JC�G���
J�).�Y5�#�Y�����{�)iP��n�l�JH&ne	�j������0�i:Y��^������"c7
I���PBO���7��)�K �����@�`��E����4U�D�8������{9_"�,�i���W��g� �������ph�����l�?4;;�n����o�s�
���$��
�sl��#�������m<��0��5������e��<%
�����T����f�4G��������d�\<)�\�4
�n���G���7�V�_�oB;���+Z!h1�"���\���x������~!L1��R%L��A�M-[�����L�p���}f9�$tq������}f
[���.�G!������������<>a,����!�dC���7��<4	T1�����3+`��i�b�)D��L�:|0l4�i��CE.VN6����J~���;�a��?&?t��[`������|�DH��=a��Sd�c�~�>�����G`l��f��g;r�=�e���
S+���/��~������O�2w��TK�]o��'�u��I�.�@L�u�����f�g3�3��!Y~��fg��>��A�c�"��D�'`74`p_���s�
�3������Q����0�����C���,G��dt�DvS�T��r9�i5�/��ox�D?�S��A�S�L��F6;��$�.[ayx�*�;���l��5Yo����|.�#o���F{5�(:�V����rp��Q��C���/�}��E�����T~�v($���?7�3��2�Z^�uY���H�m`r�|�p��T�>�������D�;��`�Q��`�h�\��~�� ������������e/X�C����~�(����'����|��{��k!O3�i��&�sX>��~	�������P^���	��%u�P����K=tK|�Z���qR��W��d��8���Q���eLS���|��v���$
�<�xy��c��
|�>9�w�����p��������L���6Y�@���;�����v&�i�����(2ii�"�*��{����e�����y������m��y��S\��'�n��kC�`����2�U�+<���a�C`�����D6�<��b����f�����$'����������������^��]^��|7Y�>~D�X���������B�@@
c�i;��l.�����kLs��M���Th��H{����e�[H�*����"�����u$��&	��J���'�+��:,^����1�K!��~����������;����$��������[5�_<z����%�H���h���3����I�wI�{R2���7�u��N�����z��=��J;.�D�iw�{=L���Nu&��;�90��9(�4}��u������,�������e��C�f����$�8h�5��A�<��|x.����W��8��>�]��f,p�Y�7�s$����=��������;����m1��Ol��=��dM���!7M����m�m�����AS���5���&�=9 u6���3�����C���3���������]��8�|�V�;�6
8���v��!|�Z~�,Y

)�t���8���3���b�$��_����M��c���z�aww[�)�$�%q%J��X��RU���J�kRuO�B�{u�FpH�c,�cr;�WD������m����a�=(�sI���0���s)�J:;Dg��L]���(��Wl��e��BJ�,4g��H"�1��Xs��G��zD-�\T���ij_��7^D{7���#)]��ykA��@0���������x&8Cw��n��������\�o��Y��1��j�6�
�D^�T�K��A3�&���S�)�Ks`���riL��S�0��23�L����M"���TJ��D8����/��{�\[#>���X%�`Jp�X/]N�H�+�y�^J��w���#I	"�O�����]�5@�"!	n���G�)��3�T|�\��2�R�����|��&Z���g-r����v����r�:�0<+���d<�����h9E�^���9j.����xh��r@k�A9��Lx�r	*���\8��W�S" ��d(����/��&@���0�t����F��5�;���D��W�v�jJ���m������4�/���yw.�aRm
�vn0c�w/
<c]�8�u����*@��B������Rr!6�$�E"	�"�r����J��I38��@��m����f|�-8��P�E8P^��"M�DH4���������^1��:U���q)k%7dT9����cLv� �9�#����wV��-f�H	9����� -2D#��E�]�W�S����������l_:X�^rEy��#������s����l�hJGR�����I�7���3l�g�����k�����|���"�V��4:X�oZ��UE
������<9�:h����E�A
 Uc�'���Myj�x��������~��	
�N�������f����v������q?�n�>���^�=a���6�Q���=��|���]�>��g�NN����8}��^=�c�����X������o_�
��\��^�O�hHM����G��������o��w���_/�Bsqr����YA>:%��oJw���2�:G$������#���P�%�]�)��@+jZ����`�/�Tv�
H��������4R��2�FK���t�%H��P��]��s-��E��{�"e�0��d�Q�A�W��-�r��� ���_�5'\�T^AFF��W�e�B5&l2��F��q��(���_�%+
�$cE�F�k�t��,TruW�1SL-l
%�0�v%��}tRXu������,&U|:@r�E�z���2�Fv5�GI#y�k��l"b�E��(�`�"�F��6���p�"���0#��(�����`Ax��[a(A'���sZ,����_"N��+qE�.�Bi�	9*��Gzb�N�������~����e��'@����
��'H�{7����&��b�4`/w��y6�����8��	�#"��t+��R0�uh����&��M��|��Xv�����|���������	F��d#����StHX�������y7n�8�ji��N���w��d#,KNdy����%���J�������jc��c�6������L�z��
��Au@�Q��(aG-�*QM<�r�����B\.X)��|���\t[�[_��4����%���72�U7���]�1k�f�9�������j��r�3X�:��1��2G���P���\Z�7�#�>�?�����m^�6��+N�V�(]�wQ��e���?�ka�P�!<�10����'����� �BdW�����_�����T2eCJ�=C�]�		jA>���/���� ���K
�U�
���>��W��"�R����lu[*������G�a�H��jS�������Z��UK2�����aI
a���H����t�AN�@�k���K,��I�������c�J��r�jz]��H�x�����������(�4	wj��|u\D'>_���.���b	�uj��|���`���M*='�5�����!�.���Jtg�^@_Q	�������>�G8�����J���J�^����7���I{{�m�.�vM�up�]��:�Ec�mU2jw�5�o��:�_:A����;�-)=����F���<$)���������s�u�}�ky����`-i��s�o��w[��k��i����4��_�Q�C51�lwZ�a�5�w[Gk.�Z��=�nH�������w��%��������J��\!��p�P�$���h��/�F���G�
�6�f�����I��np�����.���e#e������
*�?�Pa�`�-�1�r���d����
��}|���G8��^=$��|�=	2mo��k[���>�G@#�!�#�pN|�Tw�(�]*hkk���3m��J�uM-{�/��#����6/�����p�	~��^�D@����,����S)�
���[�m	���"�i��x�=k���TV�YP�3��	��';���k
m��>�y������&��x*U���>C������:(LL+�_~<�P�%�%����PeD�IQ���Vu�(����+�3�R�V�S���z��Vu�@�=�����v��n~Z�r�[?�����v7k�=�q��^����
���(H���6_��/������O�:w����4�"��������V��T���)s}�F�P�y>��|m~��,*9���S�=z������wV�����H�j������s������;@����gOO.R����!Y�x����p�5v�"���h�2����r{R_3����=���w��yP���6���a����������w�P��)����y���
�[�5A]���}T�Y�f���g9W���5�S�|&���} xBAH#�gZ��h=���{I����e-������7��/�w�/5P���D���f��0909�
��\�JH��SR�������j���~������o��o��o��Zg�[k�s�����mk�[o��eo6�bk�v_�9+�_�3+1��^��-Y�(o�����`W6f�\��#����ucj�Se��/�B�Owv���I��m�(��F�$VUE���D~�^����slI����7x�1*qA[r
8���N��:l��� ��y
��gz4�����d(����A�?~�}����x&����<����r�z��;�(����Q���41]I�:V�ts�N/��E�F�-�-��q�hq�S���Z$�X�k�4����=:�������5�%���_�&���4g��S�w��������J��
�����Brd���.����T_CD0�����/��%~u�2p�{��Vg���oQ�c�O�� ���nw��`�O�;�~�����q������W�9^�*��F�GS����&Vk��F������A�b�~��:}�i�83-X������nKp�B���?��;�_Dk'qhOlc��������]��DH)������]m��8�7����m���l���AN�`����s��4@��I`�����S��� �����^	���q��]����������m��hS��[�X���?v���x0~�%���?����c
�uy~t��xl��S���cK�P)��zVS&��lu>��)�S���C���;{�J��ckK�_��*:ov�-��&�t����i��������~��D����IZfG����1P��tH��&dp��P���Z���U$D&��j�Q������km���������0/��.�!�pr���=<R
�Y�[�z�����{8�_R8�P8�$_��������n/	a�����{�}�fm�t4��(b
� z�
�M����0�U�X����Q���p�nH�V��]�A�����1_H�zap��=�\���\��U:��m��2�c�2E;��r��ABC��\�"�!��� I�U�����u�86�P��Tl�����nU�~�����R~��a�@,eg6��w*A�CT j<�o5[�5-YxQ��?��A�]�������l!m��E�\l�����|'�(RM�M���>,�&j�aIV*���k���E	�F#� �PG�-�WF�� r<D����K���a�E;���0��6?�wGk��:���vaK�Z�{1��"E�<�"�$�zrV�,t?q	���F^[3`�r�������E�����%���Ae����%��43�����4�2[���+H:���������Hn1:}RB�����
||��x��X���P�����9�2����,�H���ADeM�)>��[w�h�2��c�K�$�m�s�t��*%?�~��5�{�g�-���Q��fR�T���=��wfW���{-$v���}�WT��X��i$���.�
l�E'��c����9���"x�(w)dr��5��0
��uYV��w5��H�������d�E�Y�k#��k�����7�X��<�B}q���_��kdI�����r����g�]T�i�g�T	��%m�2
�*��W��Z�����_��I�ev��?�����WVn
�8�b<��<�x�;W@�S��,�jD$��|#�H'�(�j��I�7��~I$�����\e�P
]_�	Q��
�w�J L��������7�v��@R�����9>3��"�]��l�G�=��:#����"��O������of���8RV=3�CiRIh?FV�������`�6h2}@	�3��7��F���>n�l�9B������9De2u>:i6�[��I���&�&Vz�9Z����P�W��^4px���$���m/�J�l
Q1K&���2���4��L������	)�_*���F��G�v�����f��0���&�_�l�����~��}6����vV^���w�y��7������j
k�Q�P���O�����#.����N���t<�|�HoX>�"%r0�L���������OG�V3�����u]��D���$�Rh�����`br-����s��A��6Kb|q�H�ED���?�7��&~�;�������8??=g�	�����%��R��-����\�r��?����9Ii�ED�b����J)���dk�Mh�3R�)+�(�����l�'d�j!WN������?q���h���|}�N���/ZG��8i���	��fW��a?����*t�AY����0���:JqmbT����"��YD���0Q���(��%�����M2\�0���&����b���,����9�]�c�G�
� �.��!���5!��	�������J�JDMQ��it�!b��;����B�Z���|^�t�d�����b���:�5��������UT+WE��m��<	��
�+�������UT&�v��3;)�1_�j��~3 K|�Y�ei@iX]���,6���m���0��V'
R�_�~}*
�m���//����&��M���4h9C?0,68^���W����l����<A�������{?A6���1,(z!��d���bbV������c�^$(����;�!D�>[�H�`�v[��#06������7�w���F3��"��=k��U;�.-$��Z���zA��}EPq��b���ihc��� �2_ ���}��*.�t�����*�J����Zc5ej�����d�b�_�@���x��h1���U�������)cs�w���������U���c���W��>��0�3�xq�]�
��������=�L�t������*��:����xe�G�~��-�7[�U
��/U�fQ/q�����b���XB+LN���R_��p%�����u#�a�h��+_��E8��v�-(��/�7��{Ow�3�&^t���M�F��|� �F��Mh�#�p4R����@���t3I�>��?o���f\S���SE9��:�:_Gf�X���@��xA�JO����ETE9�>��T_G8S�5�l�n�E�����R�^�l��*:��2�Y�g��>�,c���S����Zz�\�m�mn-�@�/O�{��p����H�<���,�B�.��e0���a���^��\^�x�����[�����*OrMe-+-�]m�����g��������r����%d��P��P1�e9_
��qP-���/"�p�_ �R���e��@�7��-�4_�9��,K���U]]n@:��s��]���ug�o�����}\r8Po���k�
17)k�1�Q�\#�?�X�X��?�F��U�����=Y�QT���w���8kq���D,�,T�N5���k��I<i��Q�>}*������������utzRGn��w'����8l�F?���������3�s��}U�����hBi��yP?��G��9���i)KR?K��E����I�W���/����)��g��3��2�q������7d%����.���\�4yT�����O*���ig"��*F����W��R��$m��gqpt�-:���r����9[Kvn���F,�aL0f�g$���1�_�\I�2=�*���%��(�?������Ow�Zh�,|6'N�
i��1�������S�!����<�j�Hg�L?1�D���f�U�G�x���[2x��4�B� 	��GW�|>NgT�'�|�S#-Di�u�����*���c����:��V^�������y������!�x8&�����l��@����%b�����t��e��H�������5�PRw��u��W-�K&}I�����;�gC�����W�����oq<!���w�Ag`R(N]����N��)�>����5����w��[� }����%)�
�g���P��~�g���WV[�)w���:N��O��S�C,��G���d���k����]��W���H�9y�-�n�5^���4��M���������k��M������*���}g5������l��ph�]�QlHk�V�G���]��$��H�Zz?#m�v(�����t�id��FGb��h�)I���_,�d��k;��WlJ<� �L��J[�A�[.�.D���UV����H;8���r�j��� ��z�����`|=�LY _\ -_h��y������+W{����=����'��f��W���r��9��G����3��b�sk%���4�0�JT"�.'����:V�D���������������-���E�]&�/#=�d�������[��D%f�����j�_�jU�{�%<�:�Z%(������������M�^�0m�{�K�t�$�����j��."Nowt)�2��b�y����0�[/�yCF��ErB��N���EA��r�����.;����u�|�X��-4�GM������cd�������I�V�?���"�������P�rr��~�A�3�"������G���U����%�$���z��v�k�"��x��Mf*��qV1N;��f���_���zI���A���<�n<�������AJ�V�gcs?4S�yb.��3.[��C*>����Z�%�v��Yg>�i��a���8�d�Y���"m,�k���~C
��|X%���P
���V:,��:�* ���\KD�B�-=�����&��%���W]�j���"<[pArH���t�����D�d�6�Q�z����jf�X'��7�D
��J����K���2���u��6��� ��})R�x�Qt���|,�������_;�u�s����r���q�����dnR�o�kg.%s9��1����� �)���e�OL�-�*��m��b!��M��)������a�0�]PQ�����9s������taf�����L�P��BD�������f�L��`K��
�"�-�N�e@�S��S�8�G|�2���`)��e��V�an�pvp>r�V���b��N���_YJ��]��%T5VA!WB%�	��L���i�/�}�w����`%�-K���/��y�m�G4��.��m��o���)��>
(f4`W�{
��Fp���'0��K���.������
�L(gEVN�,-1����-|��|�]lt�i��#�q��#����Ou�f}w�a��S"�8o#�toTW+�Fy�[~���6�������H�7�2S�(%T��T����_�o��\�\�UK"��(����:�	�#�d>0'p7�Q��a��4:���	Z^����Sj���y��d���1wBd��,���I1���p�N���xC��?zy��}�r6i'�c]qA3�Kb��@�X�+���`�����M"n��|�1Ie#EfNj7<��GQ�__�*�mF<&QE�������/$�Ha���of�_��<���������L��V�9�s��_7��)q +���V��-�7)�a��p��yl]�����7#��I���b����s�$sq�R��}5f1����?� �ZMT���f����N�%N��#R���>�r�P�5��w��L�i�+�]���6�mT���������V_�\9��|�a1�����P����#��zH�����^b$���i�y��F��p�����g�``���A�a�D1�*�h0�������������o�_�D������Gp�)�������}��E������v�B��j-�����o���m`����I����}����������q���i<B��)g"^���}1��������`U������qv\?hDo�����GZe��ygz�%�[�3���
��|��j�����<5�!��l0�;�Hju���p�e���&i��$��"�8z��]"+Y�6���%�\���a�O��(�������=~�w�9_w�������>c�b&4��'�l�N�P�0g���,9�
���C���q��i��?����������J��h�bt�����������(����{H���f���������S'���(��=��0�?����Q�o��W:	@����;�D�xz=��to6��q�$&��>�I?jz��q��E�k�X],Q([���)_FO)B.W"�X�S�%�d%���}�AaH�
�������q2]�y�@	���nW�j��kk���Vw��~�
�����J�mvs���w�����o0�
o�q�|3g����j9��{3��Y�e�3���7+����jC�p�:��8�v�ib^��wk8�����:��gs
�s;��L�5�_��lM;��Ag8,���sU=�����Zt./���hI�Evp��G�
���s�����B�#��:��2^���.#��{��#:
���h4���<���h����
;#)�j����������
j�D}@x����Y�3Co0����P�C��/P�9�'��7��8z}^�B$h��3�����,~�~������h��L/�1�]�y=�vQ	��|I��8t���o��z�+��"sv���@QV���D`�����h��-����*�hB!�������S^���V	��x=
%@���-�������g�t5�g�g�7���w���
��
�Gq��G���?��x>+	
�p���2���G����5��m���n�<����'2�(a��'�]��7���L&1D�OOx�X�_k�I�P����lT<��]!:����t��=�;�OX���A'��_��x���{dO����EF�7�����$<��,���W6j�Ju�)����68���	�G��G��-����W���l����^�������^�����-����W�[�^���Z|�I���o���O���~���o���[��&������<�x��|�������������vx�m�Tjt�/�SR�����t���6R����t9�N�{����{��Wd�����Fw���VKl_�z+�����������J�m�������n���'s��i�M�NG��@Z������-��"F�cd7R�ng9��p�p(�c/J�tk������;x����
Zfz����A���kLww~����:L
;�Z���E��@���o�Tr
����@o�(\Ksh�_�:6}~���a����hAI��h� �>����*(���^��j�;~���Yo�tv������[�/22a�9������e.����f@���gU�e�pb=�*P�@���Z	�KO2:Xe3���6��.^��$g���*L�DDX��|U��kJ�/��t0N����������54"8����\liT)0_����T)�5|3���mE�,>���i�N����)�1��^9PY�rxC���0��! �*/,�G,"�lc�R��B���*��{�v�*s]�P�����Y[���`�����!UK�e��<I]��A�=��r�,���w�iB���d����o7N�p40{:;R�����2�����u��������S��(��T����_S'������=�Nt[
�XU�/�#]��.]B���>O+���0��������5Q�<�#�,Y�5��qh�}���<m�%�$�Z��������i8���X�!�}�v������D���Z�������l>��LT7D�����
����g2E�(���*Q�zl��95buYs���$��USL��]�~����d�����o9���h�y��
^��7��]*�)�����R�TUEp�fR	z�(������<{������ed�������`B�i�����s#�M�����NY����F6�N5Y�}���i�����_���z
M���Ql }��T�����{���-X�7���g�L���
��hx++�<V8���
d
%������H��&���JIW+��l6_'o��gs��Oq����/nps����"����D��*���h
��r��t9�k�_1p�?�\�����\�U�����n��|��*�����7v����v���N/�?�-����xe����j�
�,�=m��X[j���z�l��*�L�c��zJSy�N_�e�<�lO����1���a���zf�����>�,Ny�����N���W���d�=��z���`�M��=G$��u����	���1����eP^��k"Z~u���wW~��Z+�x���������T��4�����������T�>0EQ?�F�x=�W��/?^�9Y&��4ac�5oLSq����w�Lsx��Q�:u����A��h���������h^S��5��>;��$������u�C��Yq�(aR������(�}�h6����G�l����f�N�����5�o���mVXs��S��Twv�+���g"�pi���+Cp���@Fq4���pnu��)�cO�������=���u��i4�T"���H0�6@�U��"�����p:��D_p�+���KP�
(�1�nV+�����������)��@k��A��>6�j�0��o:C�;��d���j��g�1n�/�I���^�����/d��k%
7E|�R�A%��k�s�M��&MBS��!�^��T(���]&z���&/���A�'�8mq}Q�������u�A��T��Tg���xl"2}��k�����]�����6�nS��d����=��M���xN� Yv�-t
^������Et��]���~���M���uY�����Pw�)�D.2��_2��:�p��VF��W���o�����l��^9�)���|r��	7na�\fM���7�-1�t���������J���^�d��7����uG>
����=�o4���)�
+�&��c3{��&��J	��r��{����l�v�	����N�k��Y���*Ld*a�L_�&q���2�4�X2����<������*�V��,.v5���Jh�V_�'����Q���v���f��	�+��.�)�y�}���cV���$�x��[.O#������=��
^�*��d�R����
nb�6���n�@��l�oB����!2���}�����Tw������S`��m!Tz��[4C�BV���Y�������r:���\v�$������C�JV���5��YpQ�`l�����F��5B�df$?��$�~#��U�o����"�9��`Q#�v���������V���(ED�*N���!n?{l.o�[":`�6����C�|�o���c������B>����Q�E�hoO���Q��'��!	"�	�K5��@��-�T�'����V�N�'�t	Y�p��Mf"���b!�5A��GQ�������$��g���CE������
E&�D�'���M���q<����Gx�=#��B�v����(�IPb7�;��M�/#�z���F� mA���e���4Zj����r~U�Ve��m&��P�B����D-��EG�F��'%���DLD�����,a�++.����Q�z����H
�:�g);h`FQ��Xz�2	%�b����:���(�-+�����J����6�d�Mc�������O3���,�j�%+b�nG�����4��k������_��*4y.M�L�������P��������C7��F%7�y�X�Z�?-�O����9?��p��UMSG,v�hq�L�eS"���)����YZ
?�h<o����E��gI���R��� �zz4{=u��J8��0 %5iV0��d6�h��v�5����J����\f~!b��n��p1�SLoW3�Q���c/�'z����-�����MQ�L�c�Z����\��MIct���A�M��FAu�l��2a�m6�J��*�z�v��1������I���%������`�!������\��A/(T���J��$���������8�������0�%�/��;:uQ��+ID��5Q�Qw��V�Fa��&��4�j������M�P2�h��X#�e6�l���k�$���5�#�H�4���3�&��}Y8	�,)��\_�yH��PlZ(Mb��>��GL531�S<������f�U���
YB b��E�0
��!?2�&e�xA�;��x�D�^7��Kx�
�+x&&��Ipy�(,���f���7]�s��p#��&����E�S9#
\~�dl�� a=b�����,�1?e�7!�c�y�_��C5_�����6�@����O�3v!�6�x�����YeM3�E(��.I1���Vg<����)�,8%�����f��OQu�uH�hj8�e#�g�+R�yi�u|9)�zXUR�tH�QR�
$������c=Q#�C�>�9��3O�q�����S�5.���1�}�n��,*�����J����qE�I�e�i�7�$�������y��p��>�������p�b�-!E&	�B��BDYH#�`�[�9�h��1,�>���4���X�D����F)�I�QR��T��'����������s_�a]���)����hR��T�R1$
jO�P��j|{
8G���!@]��c1"�Q�������A����������Z�����~��,�$,�R@C���1�x!�Rd!u	k(�~�\v�c�/t�w�VZ�a�0�������
khS>jD?�<��H�+x:FI���y���gg��S;=S5�	�l�)I���.8X���J����*������l,���B�*�5#�>fD����H']�Nz�R<�Lcblo�`�m��
��2[��C����c*���`��$��|!���c��J|=�W��.�Y_�E��fOl�B�ro�*u��������q�\����$�-6���26�}g^���:8"���yj]&f_s�Q�����,��5����w&G���>L�����PM�5o�Z&���c�69����N�v��'f��_��"5I�z������;��Z�G:�[>l
k�'
E`���'����8�LG*��}������c�-2�[kbo3[�,�<l=�%���Y����JQ/Txi�������a@�f��E_�(:3B����Y���� }\u�_,�� ��]i�N��2��J�8���0*��3z���9�F@��J�6������F���N)��BG)e���[g��:��I^.�6hSr��.�R�#�0����wkF��&�8���f#��N��x�L^I
���)��F1��A4��x���~�)jJ0�h��<U]L��f�"H�x��#��(�D���x����i�43l!������o?�5��LO��5b����[��>��K���}�%B����wG�����-��zvYZ�?�v���mt��J��Q���w}<r��;m����T��O�;�^�L�T����,eg������e�eQ�/�s�
n��N�B
�i�^
�,m_.X^���~� ��}��9p<@��<��&��9mM���Z��~���n�P�j!oI����6����0}y"Sb9�P������q���$���!b�*�����e�����$O�MiFc�\����1+(8a1�,�
�>$�^ThIkE(�&=�9�0u�j���*f�N1Z��r?l�h��4\���i�"�������R4�5�Ri�5�ql����?�T(oP^iMW�0�eN�P<��Z�����[�	���g\vi�Ho]��I�g�hMK�1�f�P�6��k��"R������v��U�x�:�N����gJ7�]g�D�^-��V��m<\��y�fa����]�"^a�X�(KDXI�D��,�����0i��4�����x0:��V�d.�2/BetH#��M��Tw��h������0~��[K���h��9"8����������CL'E����:!7�Ga�J_4����'��<2��b��;����;�b�h���"�p��9I[2o�0,	�4bq�:������v�	�����l?:��1�H;�{9V�	#H?���o^�b!0�l��N��1�����b�5�"�H3|�����O���&T�:�E3x�%��YN9�	�sZ��l&��1��0�,�L�gxBv��s��=F��B������1Wy��5d��C���������)�M�X&���]Vy�mQ���Lwx-3h�s��,�W���q�{�����`�|8���?����)�$@����u6��j�������i�$���JR������O���R�����	���Q��xK��_OK�/����_�JT�U�Nu,?��F8����wz��k�Z�`�d��l/���r�mek�6�/���s.�4V3��z���#�Q{��R1�}�{��'���@�����f��]���mno^�:y��-$�=Y�|�7�6)~�����H��r_�(�_�?�g(���>8=�Y���5�K����`����a|���Iz��d8`[��kf�����{o�!I��u4�R���&]�����1�?p<X����bo����0���B��y���@-e���u��&���Q0��{ck�ckc���T�
�3�n��p8H�r��K��<S�6���y_x�j��2�V�nV6�{"�h�~1��\��:~�.U�DPsH�t�R�3�y�qa��{�$���C����������������D#�����:> z�������t�g���5YS���y�2SU e������e_�M��q�����w�D�ck�vYo������"+;N�U�i$�;�G�D�\���h�;C-o+N��v���R���)����H�*`�����i��X�������
YS���a0�cj�SJ����e6,�M��H�%�*�I�ib�P���7�;���o``B�5/����n_��x�]f��T���o����S������l���Gp	,�?8�F��E�2���c2�K[1���#�l_h��l&���3Y����U����&e����C��P����Z�IB����\^Y{Z����[2���i�>�L���XV���Y��NKY>
R�8����?m'�9�S���AV^�@���Yxg�"����\*W?���m)}�$?���9��o.@�C��d�BQ�3R������������l��6P���o�>�~k{+��V�Z����|�[�Hc�-[���X��S^��b1X
}�����y���yc�����{�E�T
(]h�`/��+q��������&6'7�N1�W�+���~�R[��f.srS(�Xr����Z]O�����T�H�����t#��p�Q.ys���:��M��}L���t��yno@�����wi������-D�2D
|�k���pa��W 
��&Q+����\*����
�Q��$`L,P"Zsk@a�y0�/���*�:��;e��z���?��������9?�I��8���	U�~��J�����'�Z�G��F���_�`���}��x7-~���T���J^�QI�����R�<����g����kY�K������!a�����[��e{ks}��M6I/Cr����P �.�J�R�������8�DH�C
����n�'�s�r�5��JZSJ7���V��5��i
i�x^CF}�����(�X��2�-�6EJj;,j�kD���1R�BMi�Ef{FxR��pi�Y^C�A�����,�\��@^���MkO��y
e5R�>pR7ly���9��
��S�t4��"Z|�K��\�s��B�.�s�M6ID~��s��qLGl��R3��&���3�2��(��n���n�������F-���i"���)D�5��6��A�N%rt����Y���eq.����v7��5���X�p�B6l�Kp�&{����
�L�
/�a:����{�('\�����g+d�s7`��S�����j��e��)a�(�4�I"���I��5�I4����v�d��[��T�-x2����_t�~_l�#�<{qG.�����x����d]uBNX��L
�@��+�X��='e������c���+�/2�<��~l+�����"D�C��@������, ����f�\���%u&	�=u��I�\��uj��w]X~�����,I�B��d+A��g������*��R����6w!����{Li��4g5���L�U�!N����������E�@X#�8����i���(�SJi�c�}��1��)PL����{������D�������*1����<�P��Z��[[��^ �������s�F��
�})��%�W������m`cc}�R�D��V��{�u��][���`�~2n�������3�K[,��d^K9��T&(�����c��%I�r��%I���6�'�1�O�����_��^�����o�\ll^��_���/v�b!w6���%��N.�p.�DrQ	S���&-�����{�xq��^�����������y���t�]��)��G�����u��>�
�8����E�e�x ������K�����O���> ���.�#�AE��wk}��hM�F�K1�o��'��{������)P��OK�}����Q"�#S
W�Y�s������]�)G9K�
�*N�����6��#s��^�<����}����:�Q5R`����h<���p��xD�52������h�<�[/q��B�P���/ ��,@�����r�)��f�qr�~�z���W���V���[y��Vy��@
�1JD1::��~|t�&����j�s�J	f�C9�`���:[���e����u��j?�0����3�����H~ww���,t��q����v0&�r?�������qI�P�.Z2�r4J�m���]"���������D�nGIY(��-I�.��+%��(D#	�B@n�g� ���+�9,�9A�,��^X���V��w���s��������[Hc�2$Z�b?O��n/�B�0�lV�f����^��x���p>3#=�B�h���)���fW_M��BY�����;XuO�����J���L���D
����/�C���y���yd	����@y��h^����%���2����A��}�w�[O"��0�~��su������z�Z���z�c��4���[�C��5]��q?��1��;�[��.��|,K�A1 ���z���E�c,�L>i��Bk����k�W���5y���%9�����H��w���-��*6Yba�M�`J`�O���Pr*������"��U��V�W�)����q��V�b
ii��v�D�|m���7��U��|��n�*5}X!3�����)&��b8������%�,�G^��y�	Q��x��W��
��+�1�]hSXQ����F��y�]���[�����6Ob��^J�AEf����4��T6y�l�W+�]�Q�E��}�t���"����1�=���U�Q����3��wb�,%�����M�����`M��x~e�����
�����L/u�g��z3�M��0ht�}��-�P0P���}�`����Q4�?�E�o`�7��F����5E�x����c�ln�-Yu������#
���8n����R�GEh�k�B�]@��U��R)���O�l|+-T!�gG1u�X�R&C�b��>���V��dm?9�]�����q��E�d��=���sc��t�0�2�p�NvwA����TN��)��"���tZ�8�l�

ar@�b�����P���O�r/��PL���{}���������>E��kmT�����_��O��h�>����E���y#>y<�vXy_���m�v7+�[����f�A������8��j�m��M����~������o��-��*��
��*.��8���Z�VC�T�G+�8R8t�O�{-���(\`�F��5Ys���P�����pM� ����09��GK�1)��L@
o�:^����61)|r�a&@�x6��
�0Wl;�<�m��]>�����:����!�
����M?���R�8`f��1Yx'��F�6�a��Q�,N(�k�����Q�&7��G�*+f����Wf$�o@3C!i�f����5��E!f)�L�-���]v��\���TkU���X@&`�'$�[������+��W��4��1E�J�8}�����hQ�������M�~��4���Ut�<��X�vK��^��;��]�}�mkJv���,Q�gLk��c�����&.�=�����51+�������4cZ�;O��0��\��E���;�r������.��^2U]�9�WL��M` ��T�L��B�P.�4&��N�A�����oa:�^����s���<��xA���BN������]�Z�~w��U�3�.
�oH�{��X��4Z ��	9����)�E;t�s���?�{���O2 ���_�=�)�H�U��|�sc?Xp0f���
�Y����7%O����f�u-�77*�5�Z��BK����u�`6�����HJ�'O"�����Kr���<�?B��cw	 ���0������E'�\[��l�W{�yV�ViF�V6$���+���PBbd4��~4�Gp[�Cd��?������2�����VJt.�8y����Q���:FF����E\c�?p��H\$#���
�V�k��M+6FFvXN(�������q "F������t��dL��"	{�{;,:
F(�$� 9=:��_��/��"_$�bE��L �Eq�l����	@hO��x�����������p0����w)�D�>�[}J��2�z$Sw�SLY_Z�3�|#0Y���DC�Cr	��m��R��i��E��d������1\�ho�t�X�Hr�s�:=?=k5]�X3
z�F�w}Q�d{��[-�d�e�
��'����$�.^#}�r���&Q��xb�f��0ip�L$	G2�D��@�������u"�:s"���8��wo�����8���t��v`bP,�A8&E���"��p4
��G+4E��a)��,����3h��"����������gM)|"XBO�H�X����u-O���"��5<z�f�L��-�xc��2a%/����}����7
"���H�V�	$��F^���UJ���[�f&�a>y��YG���$�0������k����Nw����u��H��etXc�}_6�c3���paoK�$6���]Y���-%Ym����v�HK	��X+�(Ki�W������c���������X
���8������f0�v�p�z���nU{�vom��}����Jg���3v��UR4��%���g�����4������|�K�X���Jf�^�DvI*r�zI��[$n�����`IaP�E,�*E�x�,����+�����;�|�`o����8�N��xo}1Jb����{��o$ C�����,h����Tk;�@E���H���ba�K��� ����G��C����s�7)�3�4!����:�u#���L������51�������(���m��������|�b�C�W�<�V,��	��Ch��%#>�;��1H�E�b������+I�MHD������}��(��b�$$�|� $�|X��t� 	�!M
�S_�sb���2��3)��0�����
�D�C4?g��/��/X1�~>0���a	I�u���g�H�w}�!I���7B��x$�mJm?�f���K�������*�wl��$|��1����|�`$z;�������?F��Q�1�N3�;���0�"�9F�Q���F��{3�f����w79�����{�t�3�S�B}wC����E������Q�	']�xxK�m�u�]i��~�:B�t^?��qXo�{�\��{���-�A�o��7B�v�7�Q�kOmN+���Zvk��MmLdo��zvS	�LkQ&���\������O��#�wrf��M�0�������v����3d3&��/�um�6�����5�v>�-Fz�*��+��z��x�������LHrR��D���Y_��X[���]��yi�[JJv����s�V���/AM��`�6��m����_B,��s�M�8����^�����x#1���e~��
 ���4n���@i���[�z5b��J}�����QV���Y���Qg8��W���#d�?p�QUB5��W_����p
x���f2����Qor��t�kc�BH��b�����Y�����7�^��������������PyE����]0�n�1��X��/i�u�?/���.����L�������_F��I���M�7�sG�����6�e���}��Wg���P��F��|���9�XH
X����Y��[��:D.g7���?FQ��Q\#X���|j�D������!X�5������[/},��y�m�qH��y���y?~f	��,�
�t�b��~|�8n�;i��4X���P�%i�0����Q s���������7�.�eGHA�g,k��|s����6�%��}���x5Kw\������dG��OB��]
�u./�R�S4v!��{�Z��kI%�,
���������?����%%���������	d#��c1��a["i]�z�G	5��~����W��O�w@�]����h	��q��������'�8p�)����W������7v����s���<l���UN�W�������$�I��6�ah�C����C��������3Cwz�KR�u��+�{~-N�%�YZ������)y-�u�vKK�Q�~��	66S�,Z�!��<C�I|���*~�(��X[�'x�����W����M��5��x�y��b���?U���0��K������8������0���MonAVQ%��Oy�r7|��i8<���
� A-���T5�+�Q�
��
Fq
W8B�;m�������������������Ugv��`�o��E<L�oC��!83����VD��i
?E2�x�E��h����G��=Q�I��Zmv�h�>�����K9����9�t*l��9��e��������<%:0�����DX��������
���F���v�	-mX�K��9M���z�KXj54F] �m�8��V7.|� '�"p`�m|�\D��+$����~JYf����$��SE��J��;�
G�4<3��

`j��Nb`�y�2r���U���C}"�������v�����+\���d���J��H�z��}0T]�Q?�J�m�7(��@f?���c�|�o$zb��!�]�y���%���%b�z#���_ �x��^E�@���W���V�ZG9'_�j�#e��*��(��-��f	���*f�_��T
���da�G�d<Z�a|���<����EQ�%;�8�����a�c�Q�-_������$"����k�	�l�aP�b0�����
�
��(P"J����O���`��i�������WK�`B����&��3�'W�n�v�\���W��b������V�>����Z
�zp�h6���D�����#����8G\Ho�q�Z��h������o��FT?>�����^���?C�������?������y�B��6�l6���f�����4���o�6Z�GQ~�Z��������;��]������
T|��k�t�����Wb�`�������<�6�'=�_-����~`;��`#[�3l�XP��Q�ut�������������`O�
�x��I�N�����sz|���O!|{�V}@���N��G�G�K���#>=9xw~���o��}w�Z;ys|t��ON�Y�u�V�l����|�������q�DE5�8�6�
����a��~�?$jF�#������������[��|����i���������|[������������=�O�5q}��7O������6��V%��W@��m��#j��g����>F������!~������������p���;�r~
�G�j��E�D�k���|�_�>��o���wo�z;��? �6~:h�!����w�����������q������	g���PwT���������]��zJ����o`L��G���� e �� �8�7��G�7�4Z0�7GDj��7q����(���8�7��3�t�6�������o�
 �o�O�Fo�5{���w����9&��R�H8�o'
���o�O_���=���/>�]�����`����/ME��6+{��@���_	��������k���w-����i�Z��s|T�~�p�V�[:��yh=;�&_N�����Z5�?�����:�V����#��I�(����+���K0�����;�g}�b�>������@s�������F��4�h������q���w�o���[�98Z���?������g���o���q�
���9��8�X'��aD�����Z���z����V��C���7?������:
������
��/Mz�N��4O����F+:=:lF������	l��3�r ��g�	������@K����! �="q�������S�U��`��,��gM��3}�����x����-��]���l���W�h�6�X���4h$���)�`�>�/��W}����p a�G����1l�&*��!������F�������X::0���N�����2�"��Mu��1�!��0{�p>#=8o���pr������hHd�;xztr��I�����
�6�M�����qDO"�z\?�O-5��r�l�9�#�s�h�;?A��7��Lt~��w�y�s���#�/�-�����o�*������w�L���{2�"M��f�f�~���S: �
��&L
�l�p�/Ml���?i�����A���d��
�7�l��w���N�F��Y������zl8
��;���S�h����S�89v�@�� �u�Xc�&�w���h�DJ����wj��*@Tu�] �
%`�b���Y� [y��*�EK�w�6GL���xwvv�=��_����!����|N��oS>�4;�~��J�����-��`<@2O�
R����v
����`2����o�^C�pJ4�s��F������f���w�
�;y}��/�PG����~��	B�
���p�!Wn���j.Zzw":|9�9a��4sFw BI`|����~�����r��_,$_��[3��&|���?���8�/?c[�X;��J�
�����_I4��D�&T��<�(�a0���Wh-b	�`J�jV�0����kT�,�bF��N�n~<j}G��1�m��&��Y�P��!���K����D���\V�-Jk�V�,'���l��Od�2K���q�3��/���C<��]
.��+
��:�:�����">�5��H%�f��x2o@����Sh`����h!����$W9�P3��	09��^iwc�k�r`��CNI�	��_��y|a�����	�#�b��L�x2������������3~�fPz�G+�8�a�
yD��C$�;���o�EU��1 Q�aK?'a�����<"�����3@n���m�����Mem�	���_�,~��@I|�x������o���*.]�7������Y<]����e��&D����������/�d�h��u��
o.���2�}��?\
�@:=�l��Yp�:7���u\��O��
,tO�e�K4��G{�XBru��K��lfo��l��gG����mm�W�X���C�e�G#�mg��n`����x�/�"!$��'�$�_���/��
��/d����+)eI=��W��������6���KK�V���
�����F�[[�M""Q/��X��������K�#�Aq�Z�K�\���V�,������Iu,��_�P����*����"����\���4v-�6&��9���(�/�x}��%F(U�_���/������������z<��!5M��E(��`g(@��H���T��op=�Y?�$��qimm������:�?e%��sV�/k����
�/��6���WR�$%����d������p�-X���u_y��yyP',���w���(F�	�g��������e
���'	h�.V�S�J>t8���|�F�������!qijI|i�*�\Ji~m��E?�0�4��g��+��W����;c/x����R��v��@����~�x��GB5i*�u0J������nB	�M��?�=i�-Sz��S�Q���82���#��� �`'�jj����3������`����o&b�qv���w���W�9�Max�_�gX�e�� ���K���#�'e�j�(�������7j���#��(fLM���Wh��Q�@���@_IY�fH(���s�~���3l_���S�-�����o���pu��'�	i��0e��j��H���fl8e��.��{�U���O���|:���L1|�\Sq��pA~Nw���d2��a��{�?l�)w�����!�W"C2�A���EOKOXY�9v��,����8+Y������^�����7�f�Kx2����#�]�*�	y�x�Bb�������}�(0��w�CDfds�L,��:��r���4J����f<�
�,T�ER�L,���v�r�'9�Y�@pH�<�d�/���A��6 [��-�T���:����l��^n-�Bv�v�5E��v�W���F�K�|��}|��J���B/�5���puk�J�gnmW~��\�O���jm�G}��S��\���������X��(:WIb�Wj�(�I�&�2j����{o�f�6�F���C��k��/P2#�����=� ����������_�B�?�a~3k��$y���V&�\�����_����;s�F�v�Yc�������g���d_�q�E����;f%�-��w�����i�{e���j`2<_m_�[�2x���L�n:1SX��=!2�?�w�7�~5�_�Q���vz���St�������t��I�H����$<W���r��yVumK�6��pn�5.E������[hkz�6O�s�'�ATEE{���}X� ����bAN���:T�`�������A�t��r{�Ag�C��V�XwZ������s�����9��#�@�#�c9��gh���`�b�g!������[�D.���
��f��P��}����,�k��'$�����ZsA�n�lZ�������(��d���vZ�
wc��W������^=������IS��e������i�5TR����t.a�"�`��Y	_`���'��O|����h
p=�,-k9wd�fW3��q$���}��G$�~<���5�1�	
W�����q���a0���.���0��m���&��)���<����J�(l�,��S�e)y!����;�o���Q*�~s��qX$� W���{���i2�YL�~���&���+�F�XFgKK�YZo-��$Y����.�=������_bxn�j1�"��;�6�*s�^]|��62y��g)L���]����������;F�M1y%��; ���bV�y�t6�s+����q;Y'�� ����Im8��Cp;wi���vB�x^c��cL8��P�{������r��:�����>T0O��S@ �z�e
-������A6Kv��������}���O�����R�,�r��\�x�q�<x�m>[<)�O<�����6	�j)���n0��E�
�m���`�Y:~�������X�3����8���GG���l����l!���Gva
��@P��FxA����'������D�I���r����F��M}������_	��l��l�9I���YQj�
��=��$��if��.e��Kmx�!�CO���m�{��V������'Jk"��j�,�L�/}�����y�����,���3���Q�W`���B�X����9�^Z5z��Fs4�n�d��:=<�K����hw%_���qg������N����H����
K��)����Y��Nruf����E������4�����h�P�V���gc(�,����b��N3=v�a���.��n)�(�>9�:6����� ���$<�Eh�}�G`)BP��OM{4�h��W��O�n�I�*�f]�N��^f����0�+�s.<7W�4��lh=�u����2?���i��v+9�(��{� d���>	�Bg���9w��R��<��]�����b�XK�$�����u�K^B%7����w��_�},�?.���%�_^��ku�)����Rm
u"'�E6�7�M�q�k��n�/�v�|.�8��{w���J'���a�-�F)��'zx����ev��6�V�Y�$�c�n=���y�s4O��~(����fcA����$�&�����-l��T��,�5�`�huxx���{3B���m�oK�E���T�E�n�Y����PF��B����wxp��B�K�����y�r~��2K7�KX���g���T��xt��F���mnJ������q�'�����M�4)�B����l\g~r�C���D�!�8�������DtS�����<pK@6�K9����
����~`X5�KB�y?�j<[�������H���_�L��q��(_90�|�Y?�Y����9j��I���`��x{��z����vt�z:=V�yj0W�?-pI�,���'�o��/���/;d=QA��w5F
���h��Qj(��m��v�����W��D_u�!ka�Kk��h�_�A
c����7������":����SG��K�[����_SF����>I����������%p�l5�O��|�{Q����X=b?a�3���H�F����[#������y#S�B�]�����K����U�7�(�K�8�~RxBjzyeEM�'��k1���
KR��G�o&����t$���[kk0����zn:����$~A2H�
?�H������s��B���2�C��'�=���SoI��N��o���ufq�j#;��VzK$Y8�~��	}Y�?���� B�!&�Sq�����3�
M������c,��[���2$�6L����?+��r��p	Y���j���Y[��q�Vt������R������%N�d��gs�T)�Xd'.���i^��mf�L�=/WYvb5���������kV4������N�ps������wo��`�w�/���������x���>�{W�u������C����,Am�R�J����i(b��j<���������	����cf�p��Q0�9�Y�ZTo[%�g���g�m���Ag66�^B�^zL��2l�)T����\O�1_G�a]z�Z����%,���n�P�(Y�H'Zr���w���3�����>�-;�FZsVx�����Hm���n�x��5e	"���	�F�F{:��f.@{$ �[c
�xB������Q�
M��`4��$�)=��
��y�~��n���y�k��D%[a�-������C��@����s|��g*�U��Wu����~G�^ozGfuf6�����w�7gnf�';��x�����(n�@i��dNO�J$'V�k�gue�7�r�PQ���4�q�2t�H?�tdud(���#�u�<*��S��T�*���5�0ENFi��������T:i��^D�/C�@v8�j�sI��������^e��*p)5'GdG�=p
h�Xr����d�%��;�*�
�.S�;���-F�����M�9���E"��u�:g���@J�����MB��xN�)F�y�Y������G+(�����q�H�q,Ex��N��~�{��3�^������=V����4��<�*���l*N$���W����v��_���%?�G���+���c���
p������l�WF��,��������:5��F-��.Uq
M�]�6a�Z�&�J�4\HY�T<h02���!�p�DG���p�?��X�����q�8����x�zs�Z/WXK)�O����q'z�*�{/��m<��!4��!� I
b�q�hE�Pb��qZ>�
���.������O�X�"�o�'��#;a��'T��� �\�(�����mNE�jc�
��F�[���I�J<h��N1{���v�����A�M����qs��_$���t�rhE������.Eq��&j�QO�-p[�N/�������.$��J2m8RY��"V�G����U�z�O)�%'R�@�����Z���N>F^R\���GqJl� :���!E���9u�8��'n�c������vY����V[�����U�G�l2�|���R������5O�`{�m	-�nBZ��C��I�
��$�q�`8e(L���Kxd--�{d�.�Sr>�9����"��e�)���A6�Z>jxz�q<����X�!)��!�d���e#.nc^�e�55� �{������@�$������TRmW�'��5w��s���Zf>9� m�]w"x�l������9���G���^9��O������0��7��cr�z�i�;��!�	95�1/-�hW��)9��,�zZ��e��
DR���q�_���*���������^~x���V���,�-�p�C��L�=j�`��G�v&j�c�H�=X��h�)B�����L�pL�98��jMU������py���0�����9�[h����^
$���B�_��rjI%W��N�L6	.���s�G��&@``�$��/]nyY�B�i�b,�P=4���JDG�mW�������S`�%����7�4��*a��\����D��y"�����OO��'�G�O6Ov�'��l3��+�y"�'.<�����3J����*��rC�<��0�"�����0c����?�Y��\����H�-	��3|�F&"\���k�����Z�c�L�*��x�����j���O(��$�|��:�\�N��?�u���H�BM� �y��tpi �/s�&X}��=�}�F����`����H�\���h�\�uF�|x.���U�K�����h
zp��4�O����
�R��i�z�[���R/�����X�ktL�K(�2$��3Q�YA��,�K�0gZl1�wW�O�*��\5#h/$����X��W��D�]h-�t�^�����f&m@�MH2�]E�������o���S������lCSM�m�o���u�����tt�%)�Gg0��V��@@V*?�o�R�"�������M�a�&z�n�2��0�_��Wl@Z&�����re�"5��jB���6&�O>���D��q��-����vo��*a����mA�B�n��t?�3g�+uQ5_�e���s�T�xDK�8��]�{32��Sw��!��sf�#�e��*��6�$)b�|�V�<�$xw0�?�H������h��m�i6��r��HQ�\lFg/���.Y�?�m�1~�3��Y��|1���C\���I������}�U�K��<<$T���d�(l`�R$�{�So����FS�Iv��a!fD-�>�wo�!��~�Y� �s�����!U	�����������M�)S4���+��I���<�x�i������H$�<Z�p~���pnj�@�9���O�8���W����Lb��S�"�J1^;?��G���yz����Tnf���/IX�a�@��kNI_">�z��C���"�kk@�!����g��� �|X���0��N�Z1u��-�":�	V8���������P:5�
M�����.�t�.��Mo�V�M�����k��Py1T��y&V�.>�D-R�G����FRUG��s���#�t�~��W@�,�l��v���z"���o�j�����P�4��'W5EB���"p>����! �x�bS�]�(���In9�^i����D-���E ��b��\�Z�'V���^Q{%�D���j�vJ_��f��5�({
���\#=_���y���#b�����	�*4fX��*�BJ#��P9�����������b6L�xCa������Kz2�e�+YtB
[@��=�b���!����o�$�>���A��3�H^����s�'����?�z��'
[���,q��Xw6���q�}nr�Qp{>.�H�I�w�D�B���h�|&�h�"��I.���4�*�uZ��q��-���6�(�e�M"�"���4�9�`���-����M)p�n>jU����U���O?�0��t'@J3��v�Tq�p�+��#;Zc��.Gt�	������<�)^����~��,w�8b����0��J$���e=&�P�
�-YZ����
����A�Y�_T��Tb�n����Bs��	�
6�M�Y�p��C�������9n�������Ou$oe�X���"(������G�_���������|�S�B���\2�"p�i���,�Ek��L_�F����+�����d���=�b>�w��*�E-4NL�>�-�����	;�~���^��!��S���p������-�S��s^A��]�M6�t�"�0#�:V(��&�L
N��
�������*t81�V���y��6S���S�?�t0�a�(�8�����)��Y~a��:�a����}�k�L#��)��lh������FFn���J��ti�������AH~���	��&��64�b%jV�/l�����+(�7�������-l�������%�Z0�|��$��O��?E��k
��{W�N��5Z2�#m�a�����_�;:>�'q��G�W'���o9���i"s5��-����@���G+aEw^�����2La�;�`X[��x������nymjP��7oyQT2�PY9-���I����&4rvu�[��v���=4��.Dyl1����$v�/q�_?�~�7#�.!�~-�!JmD�f����N��N���AG�_9���A�B���p��d�gU��{<�F�fv��w�����IM�s��_��(}wJ��T��3����|6��vy�������.M���x����z��nU���	����D���5�d�2���*[���L*�>���;C_���H�7���f�7�
�Wl�b�T��d,mb���`�l�O�.E�w�L3z�L��>����������;�"��40d�(��������
����f6W��x��^�e���X��L_,.����`�������W�#!C�i�fRZ�}�l_�CE:JC�����P�QE�������YZ����V���y��`���.������`��[tvJ=M=X��z���d�Td�����	?����z�����������%����	(4�8�������V�
(�F��(�>{��c�J�����8�;E���q�� hS�nb\�������d�y3��#|�ZI�n<����@��nP�z9��S.gI}��L�YM��)�?�/D�oR���rO�F)rO�������N���������f~��2�&.F�>ZU�f��y�5Z�f��[��������o����n��A�2��\���2�i�&���N8:+��A%T�W����N�o��[
�c�/�e���&��aD�|�m<?�7j�C"1oD(��a���d0�����7����V���6��=�@�������?�S�>z�A�k.��Tw4*��
�R��W�z-7	Y�}3t��1y)�� ���,&{'?tV��� ~X
#��bVO��Ua��6��^1�#��������L��o'�����.nQ����[�����Vc}���f��x���E���|@?&Z�L!t��H�����+�,����<$��X3nA!�����N_%A�W	�J�^�9�;C,��>p�	o/��I�Zs*���L��y>�Tm�{������'6��]^�gk�= t���@�����3�q<
����<���
}���U�]#�@r5��x+���6�qLj�^�0��J$�����3t��^�{K���#�/���f*��0�fr���&���;h���>�`t��j���Wt���y~5������9�P�/B
���	�S�e	�>�>�e�����w8b�b2����G"��5&\8�4q����&K���*l�T�|�7�2X��zG��
�Bz�t�(����c�B�9��L�j=l����P����y��ft ��N��T�"�zus7��E����-�W�xu��$DR'3"����Ey��2�5)w����	,�q\#c*�5��1�����;�&m��Y]�{2�{r��!S}u��&X�\���|<@��a�hI�:���+�G��^yB�"���t�*��K�v~!+���"jG��j��Sp&�G��T���p��x�����B�X��}z(�4�u}�V ��(�W������Q����E� ��XR=\��q��4Em����3�+��4?Q%��O(����O��x����6��	��#5�q���G���%1�,k��6/���>����[5��Y���3fk�>�\d6�z����b�A�!h��o��#�c��'q���m�!��{x�i�BTm����)��b����_�-�a(��.KN[�Ng�i�L���}�.���b&`�~�U��G���:��P����p�S����$C�I��;8a�����h�3�c���'�N���qfmx	������_*A+�_��.r.9zJ>?Z0���"������Uo<�lX���f���Q�q�:��P3	7�EBb��\�k��I�+*�'�������{3�2�����X`">�� !�M}2bzD�&v^h���&BzhG����7[�H��%i��pF��?�{�Lqo� �����&��������0���Gi���m�9xr�0n)�m)��eo�g:q���
�F��Yzn}����l#M�����u�4Ty�s1&�H�g���_��Su���fC2j������U�����l8�2B5`K�]S\%9�����kF�>��������^���Rva#����5N���5��Cn����[�y���.���;������D*b���+D�W�`�d>��R����b
�����h����;�����CE��zf
Z,�*wk.���7�����e�
�|8��u�*s�k ���-����
%=����4��(�������E���@J`-��~���9���c�N�����������x*��G�o� �=��=$�(�&�����;lkd�:��%&b�H��x��,�^7���ptz�,bT����c7;0T�S�K��u��Q]��	U�DU����v���ZWv�*}������/-�SU�T�B�%��
&d�7�������]�W��~;F��Y�R�U�<~�)#kHP��!���J��:23��">�a�����N� ��3���[���t=����XH����H����G[}�	�Z�V�N�a��vBYV)+0dJ
Y���g���a���n�}��x�_�'��<���R��'rA�`M���-�JX<=QC�v>��C�4L��)��<�^F�&�On�m�h��f�M?�7�1�a<'��e��6�����U����v���5�\���o�s:��SS4���^���7a�L%����������p!�>����U��Z�/��Y��]�ZEIW��E����KtD��]?1��D&�3f���`���|c��W����G^��V]���e|	���J�D��:W�bb�� ��u���T��
���)*i-���e�J8������l��z2���J�������JS��8>�
�_�,�����^��rC��zS?�{���"������{ �Q�_M�BJ

���D,2�>��n	����� �/G�I8��"i��M�ym�_6E���X�9�q�[
�jz�:j����T��)dO�9{��M����U�F������"��w��q]$����nb2����3����?^��;
i�������H��Y��C�v������U�	QE��������p�|�vg�n�y�����
���a�z7�y�n�I����������(��$����xDA���+&�$��=�7N�Y�J�$�(���|<8}{v�<j5��������1j�{!j4�A��hh����kN���y�M�e�
a8�(rc���($I�������g�vL�S4h)��:h�dJ�	�6��MN61;m��+x���Y���1�8a&�����M���IdpK��f���6x<�M��EK����t�����dYS�Ky"�q^I/
�����'���Bky8��'+M��&�����	ZVI�/��7��-���q�B[���������i�f��$e{�
c�N� Fz��+��D������R*�����ne�s��5M�k����L��,<�Nq}C4�'D
a����4����Z;�
��@���	��FJ����Z03����r=�)�� �����d���ME_�(��MU�V�b^Ze�����h\K����[�(5�Gj�����[��D��$/H(���EP!���?L`������"!M�@x�h����W��3)O�����i0��~��L������#�����z���,��X�\J����f����i�cJqr3�S��US"G+|�t�)�Li����o-*=u�f;4[7ei��a�5�7Dd&=����T���;jEjH>�.��"+�fZ;A����F���;�����e���*���bH��?��>GO��W_���e���,���:�nZ���u<�*V2���(��;#mb�V�O���zi�����T{Y������{Ya��''/_nq�����V��$����'����/���V�G��:!���G�BP&�������z���I�,Z2o�I�>S�,(����f�*_L�������N�Z%j��}a������U�Kut��;�Bg��9(\�Uz�dUH���c���$��b^=���JD�.3�l81_%��*�'Nt�w~���>L�N>�|��9wwk�QBJ�pX;����	��}�@(���������:�_�S���j���v����eJ`��.���Z�Kb�o�~v�,���j�|�]�g��E|���f���ig wb��h��7v�>�y`os��������E8������~�����GI]g�f\��Jy���5B�}V��(���
�3��4��J�K+����+$�(�'XZ8����en9��2*p�?q(�{��FH�qpq��^�Q��l�{���~�G��<y��^�E��2��~�1����mUw��:��{[[Qu}}{s����j������������F������f��.o��G�<B?�Qg(�@>����m�"�������	�A�����K�T����@`���>�������j�x5�����n���lk�Mhw��:�r�}�4�n^G�I��;�=��6h�M(���P>3�4\Q����Ci�4����yq���Tr�Ve����5E|i|�?��*��f�~��!�B��l��J�q0��R�q6D�e�������~����z�W��������No��]l�Os��Tmn�����;��j�4�?�~���
����;�D?�|,��,OPL1��38D�����������ypz�l1�z7S8�a�a<��_�g�)|/}�W�i
j�M?�����E�"��m@+4�������/g�����US�BU��R[�!\j�[��CF�}z~x��Q�g�5v4N�}\��Wf�
�'G�0!P��%[
�'X�@&�c:'�sT��Wh�����L���>�\>��
-I�|��o����k�;�f>��w�����[�-{mskwk}���V��,���Z���fK������(�(BxE��`������������e���y��at��W���K���L��x��>�%����^J ���Kb��-s{���S�m ��+�6Q<���A�Q��kw��&����m�'Os[B�KV>����R��m
�|!Ay�i��%���O� �4�s3����G�����rj���T���-N�"����Fc%T�����b��e��#?q�-1)*yU������[��X��~�����hPx�����
,�W<"Vv�B�����um�*�r����c���S������S��Sp%���Z���	Y���q����5>�
����t`8X�<��(u4������6��Pxq��h��Y�2��b�N�X�K
z !�����E����B�}�(;�*��=����N	6"Z����6��������^���&>uj�,;9!�*m�&�j�����Z��`4�b�z�U'�oX�8��{���PnHP@
���v`'.�E�=~C���~��CS���]����gy�Wj��gmD����Q^.�*� ���������XS�q�Mi�r�e�O�5ow��;;TS��fa:�L
�gP
��T�D��c84��J�����g�
6���\/f�54�P�jC���z/���7
�^-Eic���$^o��M��Mf�6�wlB�^rK$/�O�Vm��������3������h�ly)��� �c�����	[�f.l��<v�~�����8���L���c@�9�aH��$�����z��\x�H�Gh>��Os���.�t�2M'�d�Ob��1M9�L&^���2o���c�4�����7���kne2LB7���3��QBN���Twr3���~G�"k�����%��F�Z������R�I�\o8��h�UQ�	���}Un�8�h8���\��~��WcX&d�2l��G+��Y���N������[�q��I�������;��\E�<����F������C�J��X�h�=������Vr�~���9�8�CP���o�D ���m�DU%n���{�O%.UI��OD��E~���b(��^�o�����K��dPn�<Hc`.>��j�MR9�����:�'�T6
�`��&s�I��'!��D|�E����m�o���'^��Cz�oV+�M4�252�����B������2���!��.-!C�
A�d�~c�V��@��%U�T��Ea���2�����K�m7oaw�(zK��0��������
n*��.8�n�S�?�G��W�<4]2~N���$.�G,��n�U�U@�Zo.�o�)
"}��������5����\�8�_�N����`Fi�������X����
�9�8Q|\!&%�2�W����I�T��eC�2�x,��d�d���F/�5C��)I�7c���l@�<fo��P;��UG�du�$�@��Jmo�DX�y�Q���6��iQX�o�e�	�����`�!�
��$��v�[].��F���/��-�:��[X��V�F�+`#3)��]Q#�a/��8�|���49�g��g2ha,k�����8��w��x���s���1��DrFcm�������������B���
yn��dN��
����C��H�b��#mVf(a�A��>	�9n{&��V0&�y#���Qu�i�h�1��&��=�i��p�>_Zaz�������1�l�v+�
��v���p�"��0|:����i�wc
�����4y:�L����x>��7�]
9^��&�4"�MR�+��[E~H{<�u��J3]fJ��a��'��Xop���?���U�L�� �����F,�@��p[��n��Y$����0��%<��t�F�M�T	�������1��B��}�!�vV?o6���C:*6��n�c���?y-����Lv����eC�O��,f)7:�b=��'��?���_����C�fI
��=G$�hc�4DZL�I��D���~|�6���B�� z����O�`Je��R��a����y���X��J�Y��QC�����;���|�#��S��N�?uu���tu)�oX�ko����Y����S��
���ec�w���Cr6XM�(=�"e(_�������=��&��;G���>BE�]�I6��H��U[���U�c�KKh��+	�����DrB%8����2�7�IUR����U_�=���I�8�N����q�$P���'���������L1�{�����6c�P,\����/��z�yC�Z�o�v�2���
��4���J@jyk��J/]w�����!�rlM;�d���&�t~��AC�!����<��YfS��`g+�E����Ik�����*�����o��Z��&��.x��
s�/]
.�`6rFJ\:���H�*����xx����x������MYOH�;�-~`v�oX�ug����`��J��P��~�2wo����~��
�>�n���J�Cs��q��^�5Lc&��s�'�����HK���<E68�[>�;����8�*�vuR/-}�������o�����b�C)<g0��I�t��z�|��JN:�����$��.���>a�;��<TZ�>+���'p�OEIf���vn3	�v7����km��be�V����D�	Q�������?����m��w�������44��<�76����c)��t���N
rW������J��g����'YL�r��[����k���2,�$��	2,w�T�v�S���NN�����^�b|
�}x6e�lH��M�U�Y-�M�*i$��#d�2ir�v��0�a5t�l�2�s���x����{�[�yJ1G���Z���X
����,x�`Z��F
���$�\��n�'���+�q(�G�[��VX4?�#u��v.�4�P����f���[�f%zN�~V�n��4�m�����N�@�*�E���4�n��c�l^�&<�=��[�XW�W�&y��&���E!�����l�����^�(����f�h��J�IqP������iUMT���������$Z�u�n���>�����?s��W��~��g
�����,��F�L��D� 4]�d6��h����]�e`j�FF�+����
|Vb�����/Di(]���V����4���
?]~Z�/z�]r������.�0�o6�k;$36�>������.3��R�&� 1P1�����	�4�t���]4sCT��;�H5�f�0����T���p)>:�4H�
>o��7���V5�em	�����N�O0���P�1����-�������B�������d.��!�y�mx3�1���/d���=�\�H��G`X��3,�B�`6O��"���{O5�������/�n���
�X^tj��%������[<���S�Q]����kA&0��3���e��K�es��6��{� ��S��m�T6���q X������u\%��7����H`V��g7�K4#x�!(4\4�r�C0$w�g�o�f��d����W���n4�@x�� (Q*���R�������l-���=���-����3N?������7������&N��z�{�j_Y���O�vTp�q��
�Kdj�cu��p�����~
>�V�����zW:�@t��+�k�r�
,�s5��pG�Zov������c�1�������X����t�L�w��]b}}g��M6�}��{X�Q ��)��"QZ��8�7S���p��cbb��+�����y��y\�L^�������V�<�7�������ZW������e(n���M�y������w����������g�0�`q��4E�.r.�R�vGrr�?AW���SMT�6��L���{��c��8���0�^�	�	��c{ouCe�r1f;}{�vw�od�����P��/L�g���e��;JRCj�b��p���x]t��Ug���]�?�8�%+�&���n!!�0�����E5��jv1���z���|aZ��T�l���Z*�Fb>/��x�0qI�*GQr	��'�z���\��S�����H�hiw�di76[�/Z�^8mb��h����.�u��z���Y�/�����x��TA%���f�g��e���$�?�4��=���Z%�q���i�v/pG�K��*�#��3�c9kd5��7��^k��/e�g��h���-'���l��A���~����4��gT���7�h8@V���&u�=#��G�l:ry�����^�R�k��5����`��Hx�`������N��B���_T�������+������x����*�=t��lU�����#�Cg������&s*~�hA���)��,����O�$965Dv)��m��E�����&*�*��
�:U�
�W�t���Q�*�����
�crRQ�08��[�%16e�R[���^u�����8�K��[�����e���n|
�����	q3*v��4�3
D'![aFvN�A��d�������*�M�#V�P0�c�(�%
5E*q������:A�D�W���Vj[�����v3q�Uk!P�%�}��
�����D����v��8�%0:�{��c��44t�Q#S�L������7����Wj�
��V���Z�K����q8{����^��A�n�_j�}(Q�@��g��s�%$[��(���[�q��
#_�~=`Wj�*��2T������%�}#�/���.'�;^���WeX����+a�^���s;���������i����q(�hf��	�4������,`6Qt:Z����6����Q#o���W�(g���`�����lL�O�������bP��{��)O��<n���5.i�.���
���pen���5��j�jvnM,�/*Qh<�$����]@Q����
f������!O_�4�F�f���`�P�T�30���rP��R�� 3v��`p4�La����s���^&��ZA�?{�B[�]����v�����\��/f\++������������GQ��0m�u���4��?i�">�6�ZY����C::�2Fr�B��R���Y����

+�2��\�0e��V�)�����.��im������n����_<����R���G�~��6��S	�"c��0�e�*L�z�����/��*�B zDic9��&�(�5I��R9���(��i@'a4��F3�o��w�']I�����i0z���X�M%`VjR���T�G���������uf�����.(�x?�I�����f�b�����+j<�`J������;��J[�7�o���:����o&�R	���s&9���`$?q�A��xF���.��c�B=�5�/r�r���z�6�.x�NV��gk)�
��^A�.������p��`n�3�H�qX�����%�����
f�C;L/;�^��P�}b��\�v)�^m���5w^��=�Tv��w?S^������U���`��P�z�
�0�O�9�M%������
���l@���>��e�,���5V��L^�(GQSr^��WC^���nS����B\�?W���k����\��lVF���Y���������KbD��=O��&.���$k�6�`��%��8�2���IU�FA
}�a���p8\�����2V���LI��l��\:
\eB���'�!�h��:�4��*���R�g�����M��`���V����%(��e��(���W������KA��-
�HM/8�R��TZKb���?���lu�X��D�v}���}H0Z�����&v�6�6%��4�-�3&�de�x
_V��P8��,���3��8z��l��l-�"U�(g��,����hPX:��x��7y���-��5�,1�����Gk�
���fIW��4��7P�-����@�
��bk�W���:���3��lEi#I7�[U15�o|�G:���_5��*�o�ql��7�a_9r�v`�}���;�O�e��q�N�b<�]%W��WRc�a,HX�.�����,'8<�������*���j;�
Qs��w��b'�.1��GFO(}�>�)"/o�h�b4U��o�YV����cK�:P��,>=-%2�3M��M�I|46�B��O���,�4j�J���:2�����cro����1,%[��'p�����?��4��M�[�'�j�'�<�	y�����D�(���)��jtO��/�&H][�$<�/�+�q�m��[Z�_�d�k��`C�anS�[_��?�`d9����}��O�����8��E��0$�A���������B_����+�����H�J��N%��K��2����&���P��2'��u�]�o�$AH���5�\��M ��G����P������ZJ�n{���b�{^X>���S��As�q�����m|Pp�����c�����3�
G��w��Y�Vj�����$�_#������rm���;��j�r$�Q?����"��%&�Z�)����E�������l1����V{4�37�gZ
<i�j����5
����d(���i88���|b�B�h���,�Q�<�"���\��`U�o]��k�\�oa���|�.��
gy7D���s��;�	�M��@����#����m���In�8�����������~m{{�����g��:����2��&���u���E�C_�bV����������R,[��0�n�Tj&R���Q�'=�#L��
}1~5AE���l*��5��&D][��y���V��MBv�a�r�6��Hh9�gz��M�%���3r9����~/G�����T�����H	%���D���1���D�P}�$~-������;�:��NcjmYr}��������e�;����
q ���9�=�Y�c:cWKW�!��&:����l����e��d2�}2{��j�'>
yjL�Qx������e��`�6eI)��Q�2�C����Oj��9�]IPo��.@m��lxV�������rG��Aap^��
���������bU+QP�=4���
�(o���(}�G��I.�h'~��a�%��������/
�*p���e�{V�)D�T��:�LE�&i�$,��Ui�������U����������MZ��Cf���7�;h��82��n��l��5���@�z������.�f���1��"�]�
>����(�[��}*G/��c��*�r��7���e�_QX�-B6j�/����n7�F����r���/�N0S��Y���~~��������/���u����EJ7:�����m�]�����"��p��
+����t��dA�]�7:������'j�s�L��T���FS�O�^���;B�-��Ur��p��/���9��X^��!����N�����q2��b�a��e��%���I��2+[�o%������:��e��u����=���t0k�����W�����9�`��C�^/.a����4���[uh!�-���t1��I�<v�/"�x�������{��9�����<����cG�Rs]�~���[���L?�G�l��'?�?}wx�/��� �0���{~H�8L�!����
�e���b���m���
���Sz$K\bQ'�����l��'GTC��Ild	�h������3N
`��.c��bC�����.�['}�4��rA���QlD��_�P����.4\'w}H��{�
t*�.���<,+����"��1���C���k��"+�`��DC�:���H�eEL��u|�������������&�,����F����r��h��L,\�k<E=��:�����x=���hG���d1���x?�Ufe�K7a�l���
��#,	��@�x�L(��M��_�~���(��b���a)�k��[�����R�AA��J�p���{���R��b%6n��F5w�S�J��lO3(��Su�E��v����#��r��B�g7�G:�gCR1�3���
�J}Y�����=�����x��`^�p�����v�*�.���Z�����<���C$�2hv�<�0�R'�H�8���+�E����*k�����*���_���<+��&W�J�;���{��~\?/K��S�9�$s%`����|���Ka�s�0�"W�X�a����1e.48K=17_<�����Q0�$~����|�K�Bza����u8��U�
'x���������3��2b./����Pu>O~�����[�R{�Zp�����t���m&���E7�^)|�����Y�K*�����yCL�������	�q?V�a������:�:�Vf��=��l>�����_�u��%- ���su	{���%H�f|VN�����;^��{��q|����/(�yJk��a8$Lx2}��(�����RD����3"��?R����_V����woO�t�Zg����
&)�XuO!�A�S;������'��X��K~�v&+�
3������O����+�BO���K
y�S�FTD�c�u-��r�e{v�i�{;]}5��|8���@���\]����F�I���i�t�b�L�r>
������.�,H�!�LEr@qzV�W���J�"|%p�o�Aj�w��m��"���N!����M��G�)�Qp���`u�{��*�$�"�C+�/�y��ce�����i����c���~@�A�4��t��V���}�I���(��dk���t�ym�P�:�Tv�=�;�v��c�@�M���N�
�G��0���t��pfSD�C��>-���E��9����x:�y�S�'�r����?�Y�F��%��%:`�h:��#��j�\t���?��e`�J}�L���A}+��Y�p���������WP���l�� �%�*�����{���%�)$�RQ
�x�bx�s����N��R�K*�����	�|��[�a��S@�R�9SN��<�~��j����wY��otQ��PF/�����jU��'L�Qg��'M�P���3�k.p��D�u�KL*�%R��0��i��g�M��I�CB.}6�(�B��:��o�H�c������UC�Ah�.��a�J��
d���!QswX��$u��d9�2VJ1��F��9Gq�jf��o��>��;#�a�?����V��2����Jswz�Dp~hP2��_P����V���o������w�W6���2w�yu����+��m$a��-�9h&���y1�j 'x�-�,�~E�;c*���QS��K���"���I|��G  ��'
*)�����e�6
��	��i�z�%��-����K�:J�@a*6u�#��7o���_5���L�q0k����
$p��2�|�bn�`�X���G~�N�T�����E���s�� �_7�=n�a�B�Y��(�]���������$K�;�}b|z�_���l���?6d�����;��g�H�),IPU��>���T��sr�m3!��K�)�\���b�r@�t9���a������8R�Q������z�YA�~)�m��1kes �f���`��R���
����H��
��_�!U`����X��^q`��z��m�<��|����d�/��L
L���P~	R�.>�WL�&R
�������Z�=ckE��rg*�8Y����������7f���!��5�"���{����f��w�����T�|\�8N8�h\	�cta�78W�Z���^&���(fB�_lM��xeQM��d�q�	��������'yWe�l)�^���$�x`������x$Q6-��}���X�WNWG����T��Cw�t�k2�*PN��������"�Er_�k����6Gy�P����n*1��.rLQ��^J�2_7�����P��1�������n�N5E�UHNbSg�|A��p��m�);A�lQgS�o����m10l;Y����'���W��k��G��i��V,�D��ug4���\���+<���1��E�(���$c���E0�����E��,�?�G%eXP������Pn��R,Bd����R<�Vb�c	$H|G���:A�,�����p����/+��B���v6�U��AP��l����1��X�iJ�nM����ht,.{��:r6gv�Kcub$���L2�������beT�&� 9��p�&Is���"Z)2k�:#3;y^.2���V��}������V&U4U=��NJ�E2I��MR+RYi�JUt���MM��4s��&�'��b���p���T��:-MF�*(S	5�'h�H��p6��+���=���Vr)����#4+Xw����m���<5��5{��P�B^r��
0(�������_����NT��7����_
�Zp0����2$���E`�$�]����C/�;@L������}�6{}3�J�Yr���,��	�}�� ���Xz:o����5�@��Z{j�I[5b#]��H�����1�_\6��Hgd1e>!f���0��`����x����l��{)�;�����.L�M�o��
�R��bEOo�z��(�3��F�	���p5F�i����c>�H������io���=9��������8����l��X1D��SI�J��{�+}et�O�=+
��x�6���H���}�H
k[���N����X����Tv�&�)F�~�.QM������_s�/)F��(`���x=�_0+�G+��*9����!�p�a�B��,�16���v)�m����6&C+��W[�K��~�+�/&�1l�X���a�h�����<�hee?�����q)�K_����������0S>��Bg2���=��R8��)b8�f��diDt��'���w$��k@�*XB���
�5\�&HK����0�������������I?2�Y'�~|�|	{���a�L���:h��UE|��
�P�"���u��.9�������1N��m�� �8
��8�3�0���6��L��Tf�$��O��l2������C
�E�X� �,�G1"�\w�?��Q*><|$����#v}d{
�ZF��"��Y��F=��@���'FP\����7���TG��R0$���\�\����	~/V;l(�$!�T� c.�,R�()��NW��Du$��h�w0�F�6M����EM��}���h��'�m�2QW^��q�������e�T��l���u<;��
���LJ������zh�Ozp4���#'uBOV?����#<4���c'�F��'���'��h����MGO�m-�����2xI�)�8�R��
�+��k�3�jS�xJ�s�-4���pE,�����F�[��)jZ�)��{�^-�iN�1�*l��\/����_������q'��3Hg5~_D��S�:=��f�7<�e����a�r�l"�}`�P�G�IQ0��=4�`}��s�~�0v�(�gs�WG8�W[E�Q`�������L����6d�� �e�%��kwM��UU5*If�"�\%���}T�B��������{N�����XN�������bR^w�;�L����5�Z8C��z�a���.���v�������������t�:������?��[2����y���`6��e<?�_C���3�x_����_���;)��CpVWyC�"�0m��3kRHt&V�a�+B"_�F�����[�A�w��O�p ���)m�\NK���T�C����,IMy���u����36��s��.'7E��������`�h�m��q����v�r�
`�,��v�����.��<��6���6��e:�]a���G�BJH�$|���c:�8fM��uVA�%#H�����,MbY�$��X�p��]l�B�%Y�2��@�k�V�Qf6����M���"�@I�������A��U&]�U��)GP���,-+��Bw�[%0��K��%��24bO������6za;�,�d�{�%���48����X;I��"<�����D�\[ �3:�^�6��*�P���e12��f����v��l���������]?���1FGb�C=�����8m[��5�B���d-�P�2�"�q_�e�p�kor4t\�_�����&�����RL��Z(�i�c���b��	i�����~C@��|�1�r]}.q�F�w#�Sb����_$�O�wY����N����RE��������j;��5��y�t����q�����IY�H�}K"�f���B��S7v%��A�����np�����i�'�f@�(S���(�9���_����:b���U��H�j�Z����t�~��Q�&Yz���hu�h\��l�{��c���f���N�Ikw�u��?"�6�mv6����Z�������������V��������Jn/ i�����o�r*]P<B��%:��%5� fU��S������u���F���]�\j��7���2�$��������+��*3�q@U�M�(K��0���G$*"�@�w�<�y0v�]dod�k�0��5A�����`��^<��Y�i>���������]7��u��\M�g�k��M��b��q8
�R%���|���'��PfQ��RXn�Q,y	DU�i�Z�3���t�q�V����L����p�y�P���K[�|�����?a}�&���;��X���s'-""C�u�7J���K���2����20�(i���i9:x<,���A�L�>s�-j���j���l\����H����P9l�e�%F?�5%k���U7�b�U{�R��zR�sj#u��d���y68��7�
�%���!���e�#����e����_581�a��#�
�#� (
v��[�nmP�jus�R�Q�E���d�)x
��PW���	_I�<����
$+L���z=?l����Y�8*����\s�w����������&��,!��I�R'_k�.E(9qZ��nv�-�����O
9�1|���:#>z�!)�"sU�k����9'��'�[4Qj�bbZc���:!��{��
���}�����*�2��Q�9�a�p��
7PByX`<S������XF���	x����%��n�R;���r��9q���j��Rfp.6�����#������[��UW^��l��n����u3����9�\E'A�M�/P�������
���f����P-�U6,2�����!�����Y�	��Wa�p���6���p�����i
��������SBj�U���euGv"/�'��/`���d'����odd�?�,������u���!X)�^�����w=	��q��`;y�)_#�6H&78|wv|t\Z�<������*����Q��A���S��,��J����~f\!�,��9��I)���7�������@������V7�.��&���>��!�L��X����+�MS�g��)p(��Q� ��;���[���&_Z�QS.���(����i6���5�	�K�\���_(�����!S
��@���4�ly"�Lc���>]��l�w	��v���
h4j�g���Up$���$����~U�5�M\��v�pK
~U�%��U�m�5�����<�S�o�e&�Y<��t������@&O9l����=�������j��x)�����x$n}H%T���P"��@
��rN�A3S����
���*���v�)�Z�����qyv�*�{���47�����D^N����Pj����0?����O{���`*��gt$�g8�V�f�IN���W�$��Fn�O�$��B�B	����b�563��-.gm103\+/�(�
�����D!M�b�hLu�5�\R���D�$C�D�z��6��vi��$���J0R��S��\Y<�$�R.i��%�
.��=��a�ZpQP��r<��:��HL��(g9����:�8��Od�G������q�M���E1A�,zrg�^j��|y���,_������>����gg�>D���I��=1'{2UpN������I�����Zu����;��31=7��q/5�p73��j��35�t:�x���!���X��������=��=o�	�puwI�?���m
8��+�Zqx�����=��J%o��M%�<�MR��)n�����e�@���[�e����ae��s�c�`�����B���i��@�����s�H6��k����zw�Ju{����7�b	bE��I�a���,KF�=u���G������i|�u�R�?�j��.FE	�U%����wWO9��vC.A�IO�e0��6i�����6{���l�H'/&�
�?M/S���U��� Lf�������c��l���@�����34[C�� ~@+������&*���U/,l=�����������g����<�O�5�V��T�
���J��R�0DbL-��V|X\��F�,A�R�}Y�.��0���n[[�:�n�|���X�1��pCnJ���D�TX�6$k����,"@\�zl������e�&�F��0����������)��q���%�
��N��3�2K�x�{5��+-:C�Hk.G����E���(��������	H�dN�����+��}[o��$_��:�A�&����%�\e%�^�E�V$�&�;�Z��*,���p�`���(5.�HJ�HnY�'�|���h�d�	A�`����c��������Mr;�9�,�T��s4���S%z���>pG*���'���d�����������]���gG������mz��u�4�dp9���lR�Yd/I��%Zb����T�
�wb������.3����mT\,�2�G�'m�)v�&���c�a�2y'nc��>�H�����m�s
l�����o>��K���j�Z����X�s�6�a�A?Z]��[����j�����0"�"��Y�\\L�\9�L9��\���CP����i��j�VC�O��h�.�&
(Y��4�������O��K�hG��X����/��C����i�}�����������+�:1�;�����!��cA�Z�9�O[l�{y|�n2�����{��8NN;V��d����,(a7��#%;�RF����X���p����f$��(�2��A~��b��3�����S��r������E���r^$\h8������������3����}�K�'���,�L����<���9@MG(H����`�����d��^�4�w�&�K1�3_�}���d�������i�,�c��or�4D�ic���:�����H����
�����v���^/|�~/�2�N����0<Cv,r��L\�;���	��F<�9����.l��p[�I����u�l��<�J)$��;��~gg}mm���[�mv�T��zW��H�7PQ�Q�(������#f�m�'���7�����������1�O�<J��U�D=x[o~_.[�lT�b0Z7(�j9��@L��$H��(b2��`D�~����/.�rh��r����MV��(%��]��:�t�5),����R�IW|�	�~�Ea�4��p�/��%ps-\ ����|����N�~�m*w��x(����Ju3Z���T��Y�GhkM���+TT 	o�l���r#p�����f
��vRB������.������	9��b��({���aRZC�c*�\U{�V��W����r;��9��z>��A�����'j�
�iy�ah85�e0:J^i���b���	�].��A�y�������f��Ye?]�"h�8KPIE�G��ZOK ��2/e��4�80�I�J�i�,����U�U��7�]U6�eK��E�K�hf�B�[;�+��p�+��	W��m����As|h�K��o�sH����/��6�$�Z��Oq_�,�i:��q}�0��aTU���9lW�!���o+���(���_���F 6���;2T�������q���A6-�����N�+4��l�����BQ&�T�G�f�cZ$�~x��f.�<r*�C��m��m8�~���0���+;�_69{���E�*�1o
���X�L
�t�B���=�Q������ae�ZE�v�d�X
f���7����M_�S��?��������#���v�����}�nD�E�|��c�T�6�C3~bp�k?(�bo�RC����-E�
�%{/��zOy��x	�%o�����.
�(&�vR&8��7����h	�0����q"����a������E�����lA��n���5kv�~�j����-�$����ACn�(U�/%N(A���k�_�Kj	(�_�ev���pd�IPGcvx�����|Y�F\Ym}��iW���xW=,��q%[����x�g4^d�k��`1��Qo;�|��<1*�{S�L�)�U��j����e0�
�����I>�|��'�����h�D�`�yc&��-�%	P�r�Q���mQ���GQ��(����90N����B*��42�	���U�������;T�Hz%Jm�����:���=}������

?P�5��}H}t�[��fgm�_���mv��>T+y�U�x��u6W_�GS�G���?�V�G�I��_��c%����X0=!R^7;�����P�c�	�Y�(����;1a���KBO����*�xpA�K��l����L$ux�n �"�����"g����h����Zw����~��-J�������3����
��X���m�L� q����� ��
�m���>l��	�	������9���9����%H��z�i+oL���:�R�(RF���yIZX���~v���G_���VZ���]���
UC�������C�v4���U_��0��q�;-{�Bv��UB	f�@���V��������J
�Jr�hQeH��F�d�!�[L)��1�4�b��������1�����l0W9��-��H��ir�L������|���L,l���������� 	���I��zq������A�*,Q��&��[����k-'����J�5����t\b��������Q)�4AZ���';/b���%�� �:T�n+*C�2���zSD�Q����0�����(�^��V�O�I�������Y��[��6v���z�{���g�4�w�J1$��`�9�uV2F��M?����.�Lf~�E�>����z��x�gP�!��x��w��
J��}�K3���hL������W�Y��s�G��0�c�0��o!�9� �w��
�(~������ZcU'�KP;Z|�#��A_������$�C�:���)�q��k[h�8��a�,8GU�0�p�����7L����0R ���lud��V2�g����.G<G��,Wf�9������I��v�%�$�&u5��s5��e��j��([kvD�6�����3L/0�p��",�'�,BkE���%g�������(���w	����k�I(#���r��T7���6�,2Be��n�����'`g?�?;��g/0�E2����������w5���L�Xw��,�.\Wd
J��*�I�IL!��/'�+:P2��:��	IYgy$x7ZmuzS�I�H�V_��PX��z���
(z�/�Y3�a��r����*��Ww{�rMWj���=���3
'NfHte��up��SqP� }
�����R<���e����	�	Fz&O���D��N/O.1��FY�qJcJ��e�&N;���v�������m�Vj;�d\l''G����&'��m��[�P#E1�m$�`���c
��0+-����7�g��f��UG
��c5��L�p�1���	_igt�:*Rv��CQ����e��3���Q���4�VH>�t[��H����f-���
A,r�3��"�?Wwb�KN����#���$���ln�9{W�a��bTn!~8w6C�����OV��[�7������>U�-����H�A�1����`D��������A��F
6H���j����t�����d&�tJn�����|��tpy5g��4�G���#����%=�����G� `"�dN)
/������|�
Wu�9���V�����'��i�$iJ��1[���u]���2bBd'�$����DM�LR���u���jd-��%����>e�~8�
������	v2)�hI����`9�O�{��p�fU����+1r�hy�$�.���s����]VM����Y����=�b	�`X��A��Ww�P�NB�����nRT����� y�����w�	�7���|�|��!�rE���=�9����~]��3�C��f�>������&4������������n>N����fY5.Q�|�z��2�y?�G�^ r���R���b�����a8)��r����Sy��He�V�sFy���YC������#wr���Gt����c���U�����Pj���Wi��&$��XIl��������}����������f*�df�m<3�[��/��=�P9��|Ld��y*�'�;�LL���WH#����rlU��z�h����p��Z��{�|����
[C�bCF�N^X���%�K����R�*o���]���/�P�l:O�O%H0��v!���H��p0��4��"F��K�g������\������u��mr�Hi#Z����$FK��=*1����^@a��?��Z#)'����^�����������Z_Du�Z*�?ReI�������T"]`PJKj$���M/��t��b%��3�V�
+����|{�AC���V��f4���m?���]��G-��R:}���ul�����?C���Y����B��~����Hu=�r�#�H)�
���SUc�N��}������<x��w���	�:���d�x�;�sX��s%�~�m��i-w)��:��j0
��e�������1~q�U�i�����
>��T-�G������)��&�-/�&��t�,�A�Lc#[cWK��;��zZ����Z��]������M��p5�A��`6��S$U(P���A#q|�6�$�ZW�,���R�v�:��N%b����c����=�DR��	������O<�A�ZC���5B���}4�k;���(,=SGpx6!%F��v`�3�n0^�ZG�r3=��t@�.����c�����!e��1��w�o��"!���]�������%������?3kG������7��DZ�>)H�=^2�ps���R�������y�W��w��ZZ��q�����g97�	Ox���������ZR<i�0y��L=K4�sJ|+���O��F�F�`[�-�&u}��c��PL��pL+��1��q=0J8z���2�f7$N��&� �	�|��p�l�4�����GE�%4"!��������y���O�v�.��a�R���~ec�O6�t�l�*�~���4�~/�4J��L���,���p�H\UK��S_��s��>�%+	d"��v���)��B�S�?�;l����������������������8��#�I�z�t��bY��Cbx4�����Ax��#��;C�g�P���4"i��5������M���=�����"y>�W�_�x
O��-�4D�{��6��6�����I���������xZ���ejr���-RI�&��Y���f�)�����j0�3\2��W�~3����������X�[_��(�!:�`�t����Sa#V�?��T"'�~���������F���~�0�L�so\7�&�I��c$5��L")��R�1}�q��qc�Z�7���6����x���g��G�
���6C���g`��?\P��z��cj�s�be��q��wY�{5�Q9�	��!	��J8�����0��4!.7����u��*�&*��#K4�S�����05��|�Y�j���V��6���{I����wFE��OhC&RopI��!Z�nY>^����QW����t�\���3�Z���[)�8v�4��]RJ�=�,�����JU��H����^���x�I�+E��������m��$�(��Y���@enrV?��1������4���ka8&��Y
L�l{�w+���L�XY���n%Q8�^�i�N�L*[h�5/4K�6���8u�\���NB%B`I��/���l���Pa�A�p�L�I��Y���eR����Xx@�0E���M���fFp����b	��
�B�za4
l ~�>�;���T�q�Q��[H2�78��{���i��H�8�{aJ[���ZvF�un	���a�|:�����q!��'�s@_��u�x�uZ�`�4�#���S[Z*8���,���8�S;�s�F��!z�"���C!�\}Z�"�
����m3�%�6d�
����]g�u���h<Esr��w��������\1�����\��gt/��M��^�v����x�(�y�4*��.���3��*S=� 7x��(<p��w5��X����8���������D�k��]�D
IL�;���n���'�����s.\\��h-J^�i�S����u�
�?.3��j<�b�af�2up8����o�9Z��v�������7����:a�<���S������7w������
-J!DT�M���W�~qQ�8��P��L������*<Q�r��A�|n��s�>�D�[�����7�B���X�v�^3�KtJ'o���@[�y��Eq��2W��;�)��]M��
@Ydw4J
�J����l�pz����������"�4ho<B����mx�~Mo5)L�Obeb�31'���?��j��.���Z�+�g-��3C�[�������|���H���>���R����s�]�`_��]u�l[����
�,��V�t�v��dmr2�|2���M{I���db\s�H
��'�#���B�%���_W�M��0�����kai�\
��e���z�u���]|���Y�.RQ�	�p0
KI"2�1���yR�#�,K�I�0i����8���f���������*��H�n�i��O�n���p���O�	H��>��U��#4�-�B` ���l�]�a��k���g35���I�Y8k��
����F�<��+)y���ap�B4����+��E�R ����S��ll���nKVU"9N���	 �j:��;���n��P��S�~d�K�)�R���u�t�k��AZ�r�<��K�����u��4��I-�9c1!����sf0)�Y0]:I�&�]����rh���!��1.!~���3�!��������F����i�e��^������LB��EN������f��*2IUc�\<-eb:�~xN��i���`�U>�0I�����a�#���a����?h�v���9�H*o5�.�a�P�h������:���`%������N�'j-]���t�i#Y��UXN�����	�	p��1��`����X��[smP�]W���m����T1�6������7�2r^����9�N0O2�/�5b�_��Py�_tz1Z�+Hnq����-+��3m�0����tu�G����s��3#�`����s*/:��w�6y$�`(r��M�[�����G�������;��U�L�$Hs>�6����}C���i�>\
zW����uL����p���D���L�+�{�!�G��Iu���O8e�]�f4[nj��,��0�%
���t�������M���Z��u������]j��v���#��s�3"N�x]U��ug��o�C��������u�:�0w%2��D?|���6�C���n.�_��9��oF�~�v�������/����.��;o4�Go��g�2��8o&��z%6f��R���OR�������BQ�1If �B;�m�.���J�zGlt��Z������im��:�w	dV��Wum�t�N|���9~��������
���_����0D���)	��n0��$i�U{<�����#ut�/C�����:���RmU{�����r����Y�ry-�`��T,4�5�'���	�{�I�)
��c�3��zu4��Sq���7�H������cv\�b�%Q�����c��|�D���J
d{}�qS�8P�2
�	A��~��T3t��L1l�������{�@C�+��P�?�Q���0�����<^����/���B���(/�DT�,��*'�����	��<a����Y�K��	�U��"X��:e%��wu���,�����w0#.o:�mn�
;A/J����T��������H�1#�sW+�T9S*c:���i�4�`�(Z�,���Z���E���t�NEm�|{�h)�k
m��Q�����������,�"��+�r�t��r��EJ����*�U`4wv*;;��0-��|�,�Sy]9�R�:��F�r�e�.�����p�S�0������	9�%W^������Kl�xK�q������Cg����0���=��U�}v���I���&� (>��c�"|�[)��&Xs7��{�(0Sb;!��M�f�<���~��M.T9�MF�����E���G<�t$v��qnU,�"���)���4������7G���AU�+1l��fT����H�|?�H��%7'�x��)�t�Ar��G���*��S�J<������N�Z�#,�^��;�����$����Fo�6n�6Gj�c����|�#��\J�������7*��c�{��Dhu����r���x2P��*5��$W���,6]NG��/i�c�������J)n3���b��GO���-(���������Ya"o��x�Q/�6n`n��dg&�I.k\�9e?Xd�H����Q�`��p)Z��feg���*��
��\�|EKx���N�2����)��x��6�o��O������h��t�)__�-�r�~7�D���hn]Ka�5�����R%2u�:�F��$��=�9�S�:��F��>f�.�����p�S�0������	9�4W��)���|@F��=.��p��{�35��*"Koy"��	�#�r���{��u�)�c���1a+cdC&�f�2U���|��$����h(�I�Z���z���Rj,I[�B��)�����f���������;c�wU��1�{�%'�&�����Pr�O6� {d�[�����;&>{4��X
E�R9�$������BM����W�a�T�D�`w��~4<o���&�:���w�������������T��IU����}�A�M9`As�����EI����+�-_R��J��N� ���/~��T\�LKo&��o�3��X�L����AU�L��=���,�<��6�|��kE�^p/�XT�� ��)�va�w?�V>��r�u}�2����|N2HE�}��i97&���Yn�\rD�G	 ����v�<&�=�=��;����w%L>�D����} :?�0�����ua�M8S��193c���:r0_8�*�~�f!i��m�z����A�
�-��*�2�YZ�<2~0������X���C�_��Z 3=���O9r0'U�Q�4I��~��jt�@������jP�\*��
1�R4Tj�����Q$T*�����gm�����C��N-9M����M%l�%�P���:�7[R�4.�i����b���Q"SC�^��w��'nP<�L�S�"����9��3w9d�!;6h+a�4�ns%��$G�,�#}�jr�-%�k�*�Xv��\)�����J.�;���.�w�������A`Q0�^���/	��X�O���l��;F�)�:������������R�� ���-_�+*��yZ�f��b���d}��xk
�o���&��3a�+~�6��<�S�H��}���L(����km!�T�q�f7�Xa>�����^�U�p�����/���g�������`�:��B�j(,�5olW6v����jes;�����9r4sJ�6�Ch:��'I�Mv�p������J�y������HPs��;K�c�@�����pdmB�`D�� ��\,<��Jl8�������!s����ko�������:P��V�X���[�~�v5������1�J^��b* $-!�c���	�z���	�l������rY��X�O�#Sx.eMT�?����G3	���s�eeT�����xF��A������G����y�m��8o��w���������=����1���/�*u�]���K���������fM���n���7���O�:e���������_[9Z��w�����$�	���"��z���$��,�GZ3m,�a�f�y�7>�=UZ$.)�'P*�p�3�L��_��������C5���,���7�Hq����[�70������o/i�}���r�|���2�AI�e
N��>�V1c��u-/"+u�P2��j�`0��j��g���B�A5XG���x6�Q�����zm�Ad1��LR�H�����Q�k4������D0��N�H�r+L�|BB�%L��@�����p*��s���<�"�C����3c"����[z�l��d�b-��y��C^'�T�K�� p�n18v�
8�;*�PGz2�����f|	�KV�������#�$q�c���#z���~m�
�U�
�0M��l���tY������g�d�FV8#M
���M��$�z��{����������0'�����e!J�����\��|�{U��jb��tf2z�l6&������{k�R��~/�X����?q�f%��X;������2��6,o��gK�>�v�8_�(����qPy�Y�S?�5�.�La��;E����y��X3z�_S���Yy�I%�S�u**
�M�Y��c��������
��5�����gk�����������-�2d��,�X�P�S�<���,�Kwu�����p���jr����9��C�'���/�>?t���K�
&�m\Q���:3
V_�D��dI�r5WKQl�6�R�,X� #��� ;�tN�����z��{og�c�<��[2���)��R����S~woo_�U���(����\���W��r�E�rL2G��1/s��7\��
��e}&#�R��I)�]�[P��m���e���z��#��f�.s���=��������W�;�;���*J{�W��b�M4F�@,Y�1�@�(>����)z��o����Ju����p���\��;����}���z�5����&�I(�(��.�r�YJF/�OI�����Z]����>ai�-��;���:ug��?$TeiQY��ex}����9��=��z8����OX�s]M%�zk����E�9+j��������u�tb����MZ	������_�e��lz4���AL[��������G�/���VK��X��"��a��9���a:0/��F�<��,�(�Ag��c��x5W��o�Ut�S
��"��L��_g�Z�1�%2�E����
_����<������.��*������wf�a&zi~=����	Qf$b�%k�ay�|-�{����#���w"Z�{x��l�����-Z:��VQ�&�&���j��DOn��h�������4/!`IV�g���A�����0p����@R2���/��0���)�S�B��Q�7�R1A���h�-��pIj�a�en������dQJ��b����/������PA2���l�p�W���]�������4_S|����@�W�9�D�>��r��#@��
"$\9V}����� nI�=Ji AH�*����EZ��� �K�����2'��&4�����q��F��X�qU������������]VX��t�{��Id�j���/�
��x��y� �^���s��Ns���Ze.V]RIuh�i	.=��|�3�����5N��W��������c�F�_Gx���#e��v����y3�W�'���Gy�iA��#@m�=�Z��;��F�	�#��0�p�����b&�����;�,�3���AF��X������J�6��n���X>$)h���<l���X"�^g��m?�\�+����}�1���J5���J'"r�TO�YN�6��~<G��R���"�XV��eJ��jL=(�p(y��h�f�4��'6�a�L<��	����)���J2��/���*�J��_�Z#b���m�K�������eWf��8o�3��3�-(���=�_�����6�bm�|-Ru8��8�WP[�S�[R���Lf��&����ip��C��A�Ha�����7�(�!������6nea������H�`v�::v��t�[r$9�iij5����"5H��b��[��n��~��B�
�#lT��@7��nR��i����
�B�P(�����L��e�t|�~Oh �N
Kl���JEAqL`#'�4D6{��#Lovj�l8f��<�p:���:e����M�Rj������Y�6�l��Q>�Il:\�(N~�������z��YO�n���������I|l��P�>��Fa����f�$/r�Bt�u���Xe�
U�"j��;����Au�f8��:_���w�[�[%��`���|x����$�a�\
o �/����d@�L���������#w]�4�������	��u�c�x���BC+R"�Ji9����4$�����Q�|1��7k,9�^�,R`rD�$��"�%�{���!��.�$�N�U�w��o��������<�*�M�(�)�!�%�C�(�Q�x�l�j���0;������	7��R%��I��b�0�o{��n�V��s
���K3�
��������&q��P^���1R�����%5����=�J��<�,^c;��U}���I��	�Xnf)��Q��~�o?w�i�6��.���&YU}�m���[������E"���n��g�*<�>q���E���7X���~��[��u��H�a���?2
9�nW��5������������|%J"�9���;�]��7�G�6�����Z<��8����oa�
�m�RBbIj�S�.�������3����!�0��3��S��_��Io��S��
���65Fg��D�4?��DvEd����-&���x�I�)>��������[���|G���]����>��<�T��S8�2Z	�%�4�-��=��\�.~��4��&8j�&F�{�^JPW�1[H��� ���2{�M��������m�1q����F��o1����m��Z����cWJ&����b�D�
��w&���c�
�ya{��
7��V��P�NR	N���Cdh��a�Y[��ym���Zc��5.�+��UB�~�.|j�3^�v�v R9���UV�e�|V�/A]��#����<6�p`�CB�LI�&����L��Et�h�z���N7���b��^��n��k������\���C�R��c���+E�a��~0Hp����DY�d�����qpt&������c���
{�"O��%5c{���)�Ts]��@X�.<'K9��S�<v�v���3n�<Z���r@{g2P�70��)>2~N����#\�N�
D���w'������w|c	
�_���������x��de�;<8��b�D�S���o~���L�.���>7-���������wre�nn�����dDH[�������G69���'�}����Q�?}��,X�Z�?f�����T�n���;��>�I��+���4���N��!�wjM%��0\�yR������i�|6�����i��j��D��������{d,y�������K-���Io�_*/E!5�`|���v;��d|����/��2��0^(s��FzT��9E���k#�
�*FCX�m������k|�n��(�4a^������}"#���x��|���|���-ME�hu�=�����l��|�UY�L\��4���5��!���!�=�H�,Z75���n�����!?q�=����,�r���`���F��oq�Yw�v�k�![,3�T*r�53o����L��H��2��Mf�?A2��F�'���
��7����/�!G� SI�����E��N����u�
��0�\���3KY�u_�t�X��Gz3(�FQ%$1x���z��E,*�Ex�Fd���a_o�������=%
�Qt�^����Z�>�������$�����jU�v*��D�W<���2��%�(����Vx2�F(s*�H�+{�:\�����k�ux������J�����c��n�3V��\�%X�;�&5�I�@���K9!����U|��FY���W�f��2�u���U�a���b����,�����2��w��v��yb��%u�fQ���H'�����fm�b������_D���-[�$����CS�N[N�#8��!#���8jC�Y����(����0�iTr���7�������c>d����o���o��pY�x��:�M	�%��w�P��d������w��(�e��.��W��EI�����
,�@Bb���r�M�_��";��s�qPQ���]�lcP���,������Y��hD�B:Y�T�}=�s4~?z�>6q�Ms,0'����!h��x�9_]���KC�(z�!�-&-xP�Py\"��b/9�� �h� e�`�j�>�����sf"�����@~3��[���G0�x�j�����]������T���"���^�L8����x,�z6�I��rCc��,��p��l�k��������=Hz���^R2����}�����!Ey����J2"�����io|qI�������d�n����G���<������=&�F,b6-�e��(|��g����_����x���Y�w��\}�����d�e��F��]�h{�	�����b�:q�S�iN�����.u�R'�E��(l����p3�������<�M,�[r,2�%����
���3������W�����X	��~~�n������FU,��(�Ys[R��?�Q��\__�����X��������
�a��� �����T��C��ZEm��Di���+���3���m<��)v*����m�����c�,f�������C�r:��F�S[���L=[b9W�96������|�������GI^������A�����aB�(��d%�
GGu%�L�Y�e�,�	��i(�2	�z&��c^�~1��������K���i�1D5L����S���<��3������;�Q�������t�s\��.�l���9e,��P'�yZMb�7��~�?�2�|8���Q<Z����tY:�)J5��-4"�x��Z����Fg\=
F�R��B���#.�U�`��}]x��K�(��=u"K�iN�8��!����4X~s����Rp#v�E1������'�{��'</�q"[>����\c�k}����v��X�H�<_�kL�����46T3��o0��I�������4�EF�A?$���Y���(|tvi��XF���r��d�@��3�~����p5��]���W�zD"���R&�����v��d"B����;�R}B�xq�x����������Q�k��� ����_�J_X�+Gc��!g�Z[.�}9��c	1�4��D���gK>���c�(B�lS�0Gjz$a��g��7|/{�!SS�hKt�i�
���}L���AT�4z��lJ	�g���_�F~�|v���B��#���L-m6!������E���4�2QmQz/�Ip��cja"�,�N,�^_F��Q2t9-}9�a��;?��)N�t���\�L����8�$-�^;e�M%�Y�;��Fo���'�Bn�@�%�2����Vg�Y��uH5��������H�*�R���Q�p�N��Vv�O#ohT��JTc#�)�
�t�Z^l�~��nU��Zj':kG���o�H����jU�6���Z��A
���z����WP�T��YG�������q�-��I��go�yk�E#��p�|��m�q��;�2m����U>s�
��B+pc|y,��IzB"���j���!Ji.���������[�j2E�;����Q;V�u��<s������a�s���"�t��$�l��(����Y�-Q	J{A$)�!W�����!b��<���&��S
�x�6(3@s%��q7K��� n~Z���Q���X>��k�L	�����X��
���i���wh(�"��_'k2�`="�AMxf���5�#_s?�5�gn�)�t��*K�T�@��*M6��^ti���jv-U��"����,�������`\QerI'+�$:��J<N�on�km�������o��k�2W��x!"lm�^�d�/#����w+���v�<6u�..Qb�\��\�`�l����W�r�Z4NI9��',.��+0T�+�E����q���$���8E$�L�������b#�z	3�������Z����A$|d���u���u�
[�&�[���-�="xW�r���JN��|en�2��O��SN��R�
��Z	`�]�|,P�xPM�e��_��c��FQ�Y#A�:���>d��a�vG�a�&���q5>����UMB�8=2D�2]�#]V�.���*k>-�_���/��Kg�fW]Vxz�H��V����W4�t����q�<����"����	�,�N��?w����U4���-x�0��N�gN��
��
Wp�����VK�����-�5�������0I|���x1_�����"���*�eW��s����X��>�j<8�
Mg^�(�
�
��"����@Y��*�����M�o�5L	��SB=���Z���
K�F�9j�\�1T��K�_ �"�������{��V���YN(cL������dN���v�99���N��n��x��|����60i���f��N�0&	����,�Q=H�3���nJm�cw�AV ���L,B��:�?J��N���'S�},�-�"�k��W�H�'��5�Zf������o��J�72�h
{��(��2}���*��y�7�e�G#H+&7"��������YXnU_e��������A���i7�~DL�|I},'"h$64W���������GAv����w����%=~L���G\G�c����Xh��],����A�w�
n��*���UP�h�X��Y7U��t��"L� �)���2�bZV��_t���1���������Y2{?&�?�x��-����+��r����� �����@wN	4|Z��+�v�@����\���;��A���"�'
ZE���@*��
%&Y��DK�,�EDI�����j]_�$u�)3�v(ix�G
U�D��X���x^z5R���d�h��s��� �8������`v��rc�	���S�Gu����)��uL�����p_�d��HcF8�%������1�1c!���0�u�k/��u������E5�c��alC,���j��<$�������G��~� f�����N���LyJ��"K��%z�3�5�We$�H�X!�R��T��(�#�D@�*�-%U)%}g�����d1��}�C�������X]�4���p�Q}�6���������Hc�����R�0�+*7���SS<��j����"4��',�[���6D
��p�P�b���%�<�@��]��-����TU��)X
s��xH}9��UJ-6��L���^`�D��t�<����*����r�0^�h��}��Hg�:�r,�5���;�M�35gL0=v��P�l��!v������.8���.D��~����IJ=��������p+j��ArX0}CG+�rVcE�X8��)�:��)c�:��_�p�_��Q�zc�S����uq
B�'�-����b� ���-�D����|�z&��ilT"x���x��>���W6�s��
V�U�m8:�s��evo�~����
�BJ��d�e����b����,���wz���D�a�I�l"���2�m,:`�Ud��Y��zo[t��B�".r@�-�9a�����c���/x�K$��1����kqs��w���j��f&r���xU��T��o��l�����l��oy	,��c����KS9<�
x|5#����(Y������T<<�~��R�2��p�����J�&x�}�I������[��S�����y#��YU%7PM
��P����:W9W���*f�����9�c�
�x��X�r,F���2�V��D��I��6�r�@r^���E����x�s)���T�n�<�r�������WG��T��(��<P0vh9�����x������XjqC����5�mz�JJ�����_������6�~�V���*�Ya�^���zm��6Z�
��s,��e��C*��3+p��.�Fa���;Z �������c%���c�����/����l�����P����0 ��\�H��Ha��������N|��B���6I�8L��U"U#���;��������\������g5n��i�WW�+���<5��$������2�t'}_:b7��R�BY���>V|��v<��;N/�?C?�$)�_D��-q�������U�2;�W���3�E �N2�-�g�Tn4�=?|��*�JD��q����`0q��Vc���41�7����rBo"3A�3|Q{�`h��9]���a��d��U�H�m$�|�.��^Q#���18Hr>����`�]��;����E�����ew�Z^�#/^X�Exo�E<�?q�7�CA�x�����B�%���hG�
#l���O���L��om�;���pN�����J��y,^�l��4]W��K�-��JFT�S�b%��%:��S�J�O{�0C�f�BsmfU}��p���K*�h�`1\���\������]���,v���Ng���c�����-�`:�J��UK��3��������9*��H�[]Q#ZA�n���.#�mNF����b���Bf��W�u����W�A�c\	�j��Y�e�.�k�	3���e�X*��w���fFTlI;�Q�\�t�z������z,^�B�,��Bd���0���
v�A�	p%,<jp}��V�������o�����gt��#��
7q�8�Z��������~�+a�-�[��;�QQ�<�p������L���L������j	\M��h�|-��
����)]b�&��_aB�z����C���#�]���_k�a�:���.{W���:�p,�L}��Y�v�2�)]�_���\Q	�)O�^!�U4�
,�s�Hx=�����-+�����r��<�����j+|�$��q?x�Q���PvD�R������j�*�i�-YBwQ)�G��RPah4���-B^��n��DF��A
Mm�������F������,{��
�P^��F������L"����+�T�����BjyA<V#�h��X�	8�&�EW�	�����q0�M6�;���uM�8��6�9���6���^QU��-�� 
�������9��9,�i���������BR`���l�N��xG�������w+�m3 v�H������+��	U[k.��S�r�-V,~q<���~
o�Mf"�2O0I����^��CF���K�
}-lu�|g?v��<�H�e9�����
��J;;��gg��J9 aL!d=,!�3
��Q�d�W=������>Gg;�g=��}������}�5w1���3���;{��r����w�4���)���e��3������=��9��'�Jf��V�v�3�%E�d�8��>���_7f^2y��{�B�Q�������L�rc��P�fhV12b�������y!��x�/
�H�����rM���Fm�^e���X	�H�g���7:h���N./e���f�;�;3[����c�d��m�.�y,B"~}�m`&�T:�^��1U�6��k}��n���LKgk��V������s|�=;��1a;fc��b0���V�_]�P����FB�(�#���yQ���M;��\�w@c�L��,n��a���[T,�����jUxp�zl���$e?@k��'����,'�x��0�A���g�
��1 xJ��+H2���S���d��c�����(o���*/9J�S�;��u��(�Jn���1�j�df&�k�S��ml��$�3�����Dc�������-�����s���,d��C�E���U�5-�Z�i�������'�(p�����I�=���]t.�����~���������h���T����`�.��O!�~���F�7��"f*���MDr�R�?�T5�^+l����
�0@�2�@���P��CL���]�����v��"�V�z�
����-^���,�6�.���s������ |~~�wq�.Z`�?�����"=����+�)��Ab�+$�j��p�
8��)�(Q�G�F,�����h�����ZZ6,�����gb�(���~���MS�:�+�m�.�x�[B�$��aoi��F�L�U��0�`>� H���a,A�yE�E��C-��emH��S	�ecD���R���i������2�>��3|v��BP*��������OLdj
�c��,8��%S�`D�yL����e�����NI?���
�4�	��BR��+�<@�!Ft��l���<E�th����P3Y�� ���.���06y��R@�?���e��_>�qS���B��Dn�]d�����tWDH/�,Y�WeNHv�Lb����*����+����[����oM�B�D�(=b���}%@���������~8}}�yv�|��t���sptx�����hss
	v��<|�]eOp����$��N=H%��A����
�r)f�q��qe7���!�L��o�""���(���*a2�����=�����+�����{��m�Pk
��*Z��V>���QRF��d���iK�{�;,����eu�/��aG�����t�l�+��[�3�F
��:�kPZ#�R�"�aLw�PX�-�_rY�\-��$%�(�b��)����������{T+(�_�u^&����{;�9��W��?���.<&bZ��R<��q��wOIE����r����������^uHo�3:'c7j�4"D�$��(�1�!��k
���s[h����,���!�}�-�T�T�@a�h�����:��������n�\C��6��b�7�`����h�3O�	�g�8�P�)G�\�3�H�_)����J��T����$��7:h�L%��rf�X���O��
7��l�4WAy>S��N���c_lP�D��
����
��	<R��G��l�{��P�����������w:��Y~�}����������vz������&
P�:-�F�<��(����_���	7��s���..��ri#���/;�;F`�k�����c`v��|G��}|y��SK���C�vD�1�
4�_�o�����8pk���M���UG���"|�������F����hi�g�G���{�������������o?>;Hd� ~���� ���������&�D�2���F�]�K�L��w�bi�@+=V
F	fU���JI�d�R���L2+�-9Q&�4#���f������g���
3�-���\�j���	�)�p�^\D���1����� ���Yy)��z�X��m���)���5������1$Ui:[�
�#���(9
����M������.^�2;T�fay��I�
�	�������
�\2j^�����"%4.��E
�*NJ{!lS���2���py}I������v���H�t0�.�r�
1�E8�L�H�9�Z!A�������Ie�&3��{���]�)���i2.�`��]�9e����;�ZC� o�gg�^?�H�h:�=�L�����j6N��#Q��|\4(Mn���g���F��8��7�����v�A�^w���Z�:c���
�,�����%�Pf���T��b�gx�+��B`��d�O�.r������A`��7T
�.-���B���9:x���o�8�������{?����G�u~�=�������@��z@t0��:{G�������
d�/�r����E'Y�*�Wd{�T�?J��9���.z��P���_8�PK� ��B�����C����������>]�-���%�����Gj�.Q+'�H>%����C��Z�gxs:
.B�X���k^�6�z�k������G��$�����T�>����J,e>�iH���zB?��*�����S�U+����Bx��
Hi�P`�h�
p���#����?�;�C-����#|�A9�Ka�K�
�v��F�����K0oa��F�2�yPe]��%� z ��Ha~8,Sv%����s$�m/������M��'e�2���k�g����A���o�����W�h�`��|,m!�V{��A��U��	���'R�����
%�u$�x��I&���7��B��b�@������v���	� ������.�YC���7��cC<��eQ��;�#����^0j��:V������
��Ng�~7�^��Cr�ayYv�JU�v�w�= �5��WT��.���Pxvb�mI}3�"=�����@j�����x����K'Xh����j�9�p[�|���'�<���j+[�����=>>>.-�������xr<;~W�qS�\���)�[a�[?RSjb�j����3H[�n��axM^Mi	�.Q]y#���Z5�j�����J���B���,L@5���5�����
���L��v�S4����
}B'08P�Q��5e�t�.�f��-|J����S*{?A�)R����l������:%x��b��4
��d*(�A����7���������L����{�"�2�
�&zs�����7���8�=.W�?}�����o��w�_�������q�����zw���5	���6KJc����V��)KofoA���Y:1��.T���|��J�������T�h*�Tc�s��������B�HE�O 0���S*
�Y����pL�5����*��V�%��]����oVN@�R��8�N����o���
���K>������ ���P���1H�4?������v��k�l��7Ius���
��mx}z�K����-}��Y�0���:����[fo|P�����[�xk��f����1�s�J�}P���h��A�O�Z�LQ�_�v�����qH�O
o��'��?����9�_��`��,�~<.U���M��fe�
�������O���U����]����j^���qw���-���5��;Y�^�>�>�>K/����G������xb<I/����g�����;;�w����#`�6���C�{���z�0%b���j4�(^�5{R�k
h9������dA�2#>-�F��\G%#
�v����F���6��o�5���R�6T���������B���Y=>�.I�<�����{v9����5�w9��$�"&�f�aeRQ�����KM$�^��z�u7��D>��A�����y$7*U��z��V���yH��K%y��
(F���3AQ2b�	�@p���a0}[RH��Q5js��"�`(�e�3}e���X��A� ]~y2�����($�|j?�'tosY{o���2��?za���#�veI���n�d�y���Fe����uh��[�.���b��\�B�6�Id�K&t�q�������\�	�"�Pt��BQ,W`�}�r�H�9�c���k��\�w����h^�_h7J]~-��7X	B���a�A8*����{b�&����Kqhr��+��������g��~R%���td����/e�*�.���@��l���/M��#�{�gUG����D���W�"��W����Z��������Cx���C|�o+)6F��s���a_��Z��+�;�u����z5b���K�9� �����t�����2��y���N[���O���MzU���D�s��_�dLU��_6��YiR�j���p1A4�����h���[()��k
�S�3�h�����}�l�����\�|������%���--���-��`S�]��;�l"���X�k�w��s�Aw�|��I�v\�[ltk����������U�8��/��eY��aT�������x]� *���C<���Z)C{��Q9����B�NA�|�h�;�
�E|��"R������KJ��N���	�DZ~��������G����-���0&�	A�S0��E�]��F�sV7�sV�7j�W��d/?��z�����V'��c�v�(y��t �M�iW�GP���������A��X��v�t��D��OI��k>�l���h1L���=lub�.(��T3\�F?�<�������0�_��u�K)�7�<o-l6��Fo����;���P�6��r���
�Y�?J4f�����v���QL��=�
�2"��#Hr���T�����p�l��r�����3�	�g�`6G��p8��k�*��.3R[p�NAN�~"�,�{���k�b������`_d�9�f�v�~pq9�0gU�b3�N/�����<��B����t0zYT1�*���R�����f�N��1�>����D�f��!!�>��uIG����08�-n�{�}~>	���'�R����7�)��\_N���S���e��������?�-��+7����o�>dj�	K��M\�s�m�zs�o���F����I���|<aI.@q�Es��j	��4��
x�o����w�;;���o�^�����l�$D����}���H� ��8j*�G�{0� 4a�pf�+���y�3~?��}��1�
��d��A�V�3�'��5#�s�������:�9�y�Kd�IIu(�C��f�MJ
-��u6�L�_'.�$�o��oI���
���m�g
�����������Ph7�M����{�Na�;��*����]�3�[�ONKKu�!D����qa�+�Y���9=�8;�4�Dd��x����������p��k�E�������E���Ijl,�*��C��?�Z&�KI�M�t3������lc��J����6�G�h������r���Y����G�q�,qvUKd��#t�)�@B���`G�GWd
m(["�;�����D]�!dt7�W�������)?�8��O@y"��>z�����_J<Ewz���+�|$�~����l�FJa�?�����kZ�\�An�!�-��Q��[GA���z����"T��{s��
E���v���Xl�%xj�f�\�w�VD�<��	@�����qc,g
����)�����z^���4x"GD�������� ���{i/u��@*��I�����T>��MN��2�m�I�H$u3O?�N:��.��tM�-�\���PJ���J�+MWK�A'��x�<C�Y.I^S�q�4����B�7��S
m#Z�P�2��If@�S�*�d/)(��m�n0fg���?��x�0�U%:��8t<&������w~��ew�@(g�M]�:�yR��G}������������P����h���Y��8�����[/��Ut�g��!�����M.�X�:��r�
����P.�P�6?y�<����dN���G�d<�����s<�|��/�S	7����3JTS�0���TU#�hQq��Z��2%����EB#bbg�E�^Qf��t|	s���iD���B��H���t�g�T���%��-����V1��b0;eWG9"��{D~~��9,�rg(��*b.��]E���l]�%��i��$�����i���8E#v�|�X.&���"z]~0�_����HIb��iK�U�h��F�o�Z�e���_���a�
�02���G�(�a��?��=��}��g3�1Q�J
��W�?��Yff���/��Lk�{mt��=���+h���L�:���qp�6i�i���bB�f�Y9��`
jEt��q�*�-���heD��Q3�k�����3�ODD:\����}M���de0���P{�$u�vR��7������m����O�4�J���53y�5�*J�}��G����)���H$Q�wNR��*�_)SA�H%�VeA!3�F�Ln�R>M��o����&_�$�v�ZK�v�C#)�����De�u��O�T��J���5Afqby46}8�Z�l6�|�x>��)�����E0�Y�����,�g�n��
���~:I4��b�������s�����bi�}�Dh�J�������l?nz���z{a�C�<"l�3H�p
5��|����{*���4"PJ/���dX<�Io<�0��e�%�;j�I�H*$n�y:G�~y��XF�K�4���B�:k� �5{T�,|GKZ��h������@3g@���
����9'���'9��k� �B*�5R2����9p�}g=��t��'���F�$��	�C��a����2�K�6
�>8�%]1/��&�j��v����Vjw<{[F\11�A�|(!�"Z��eh�$3��pa9+��1�6b)EC1�7m�_I�3�A����%���2O����*y���zg����4�"$]l��Sh
�
V0��G�u��2�E���Q���&�\s���?
�*o��ZI�~�����g�d���aI3��L}�%������8?�<�>����B4���-T&I5���`�2��K	������X^Y}���03���5�I@U@����p"�{����_���tz�������aC}�7tc��.���������K6�������n���)�<��'�H?�)������\�g�e�JfF���V���<����y��m���p���?�`ymZ������3O�i3�
4r�R�����5��Y�0��GB�+�
{
o�����#������p�N��!� 5�[���*J�Y�)Q��������#��Rw��i'�)Fn;,�%/�x����8��F��\��#p���K/�������P�;�d��8���Y�����;}%���R|����ZE��	��ZY���q���&���pX����><=��U�g��2R���Z�V�@��j�@*x5j��2G�%g]�X�q	?���!�FQ�HR7��n������R"\J���N��I���y�t�k��/�b�������mj���	�������������S����w�r�7*&?�<��RG����~�A�.�d���0���S�a�����F�x�H��lqpE���e}�|���	@�eb��C}�-n/Qv��;<�D�-Z�G���;���������?�����c�nQ:��x4l���E�pk[0�a��i&C��%�1�;,$������4�����XB�35>m���P�a�����#+�A�
7b��5<f��J�}mc>1gZ����iZ�Z�_�rI���<Q%d������F��M�����D��}�x!����UA�_Im�j#��X���M�]��Y�Kb��!ZR^���#����v�P��!��3:�(�<�����Y	
:y����V���f���WP9
��6��+��%L��������.L6��B�0N�����EdIq�s����st�;�H�����b��,��xN�d�#���'zo��Qt*�:w�0�U�g��m#���\4*��W�C�X9h�`$}=*<��*���|�\FW�����m���5\�����#j���_�3x�a�(��4^P+n�'Z��	:IGpx4�|�+@#�>P��rO?��!�p�3��\2�M�Z�Cc�e{������]w����W����6!N{-��77���������q��C���:��$!]������u0��f�n���FZ��4R��e�|<����	���S�Y#�Ct^��KL ����\o<�����N�p���5��k����<�����IS�]�L����"��j�cf-9<.��A��BP�>�5D��������})��3�=���)���6o��do��adSQj��l��m���&x�8t��B<{M�a�mx��!{������=o���nZ�����*�yid���%�3�Yr���&�}�X�f����s������=:c�LTb'�Q�R)�iw��n��:�g���#3z����s��k�Vj���O�Y�W�?���h���)����c=�=�mE
(~�
����\������@-%syd�:)�%�x9��q0nC��#a�e�����L`���x�~s��g����-_P���D�jJ�fW��X�������`��������t�O���HG��5����\_�kr�������:J@V�q���fX<89|5�|�A�p[�
�f�����bb��k*����ZksA-]�����dW�Y��<��:E

�@C���hem564��aG����%1�9(��P#�`�}M�����U��q]���$����x�^������r���3�rK}�=y").I���lK<�9T��%:�u�����l�Nxr�+��[��3���?��D�n�����/gy�f�p|��H!�{y���b���������Z7����d��L@Q������nnj�*��}v
���\"�e��)Y��F�d'\�~M�F��S�p�N�+F�0^�?T�����)f�@�>�S�������
(�T�����q���7KaJT �7J��X��d���daP������e];��Nl����n�u�HQ>��<���nA�.J��Y���!K��BaO����a������KH�5��!{('�{/!��.0��B��=~wu-���f�
�,
�0�
p��	y��U�ZJ\5��Z������f��p���T�������zmR���^<!��	3�h���.0����Y�]��dp�6z��L�����o$+��'�.�hW:���R�&�Z���TQA1@0OC���`$��x�eU��Zs�[����7��$�5]�L�8j�������V����bC�vV�m���0�S^�hh��c�T�������aw9����(��[�_?�n���������:�d)v����/�/���Edo$�$x=��i���g���T>��QBcZ����
b���"��� hK������l�&�M��b��z��!�zc���s�����jnw�$>3�����vZ�q�R[n��h��4Ym���i�N�1���7|��� ������"����������8�)rm���..n�b�j��~��`0���A��1�|K�>��r ��ih5����m4����ag�Z��x���3�=�����za���`������0�;M�'IXB6�X����F�I���s�	�l���
m5e��V8.#��9����oV��M@����{�;r��~6u��{5�ECH� "9o'�q���X�-���������3a\�`���Q��	����#�0M�@�/�
&�Sq���\]1�(���`p��P+�J���V������A���Yi�[�`��dl�p�kOd�e0��LC�3�pj1�s����:��V�H�8�O&�n6�Zsm�.��l�)G~�R�(���%�J��"�k��.��l�������-���S�}�u��M�f�)��
��myM�IR���{b&���](%d�S�|	�:c��2��V>zk��/���{�j������$��z�Y Zp@B���.�pj�����dIR���	��p�K�~	4I|��4�� ��R��5g��A���!�0m���
Z�'�����\c�,�M�a���\2��U�I�L�������i�2F�s-�.��\��k��i���M�%���n�7�{'k#}��1T[n��.�]B�1��Y����Rf��-�����;������	}4F��~a����Q>W7����Ll�p�M-�zj��<>K�yi�dA����,����(�9<U�Q���[�[��ms�f���������t��9ca��5���z��6���!`Q�*rv��3�2w?.S���G�lSR�[iN��<^��|n�M��Z����d�\���pfyj�S�sWM��|5Vq�cg�����^�|r�7�6��tp�x�C�[����5"�t��M��4�d&EF�5��^����R\]1���"�8��Z�u�-��
'7�x���;��(b`879GL�@�����;�+��Yx��j��8�����i ��eBf��q�n6�63��x"[�GGV���3�
���l�q���0��s:�k�y`^�b���l%Wov�b�l6����J�����(i������V2�"�D3D���w.��mL(���n��V7��R�^'2�2����6��uG�~�N�6����XU��Y	���D��������g�������(�:��1��b%�@*�;d6�l�8�UI�'���^J��@���M^��y >��u�n���V���:��e�c����BOY0$�&���kc��G�~JoG�4#���L1�o`dKY4�����M~��O��~�}�l'�S����1�)�
����[,E���%���9m/J�-0���\Z�X��0]F�O�����6�?Ut���8;t��d	s>���;R��VZ��H?��K7=�Na��61��&g7���{P����Yglb���|�U6����}mQ���'��G����:��������t024@-��rj.�{W�V�/�V��6v��PB���<uu��h�g�������	F����,�|L[B�e��G+p���`�'��,���^��W�''���w5&��
�	��=��u�����O�������`t~��u$��o�M;q���c���|?��+��E�O������!�i0��	��k���p��Uw8�(F��ze�����&�q7,���p��m0%]H��S�b9��,������~xF����l��������:�uw��������&�������=�{�&J=������w��������[&�Ma��B:{l.����������������a�`w���w��xm}6k�k�U_m���0�
K��{���c��)�g��m�v	3@��`���		�Z�og������F�[��O��;u66J���_�O0��(?f��\���(_���XF�OK����$��i����1&����J �'�k�]
�Aw>fW<��N�����"�����,�aU��V��?��Z9��������:��^�$��|G���F����@���H+��TOy���g���q�jm� �*������EjUq_����1T�
e�}������w�J��'��ph�xI�
oq�9��<W�Y?�����?���t5���!��������:������
Eed/�u$5
��y��:��)�i[|+k�������j3��)�o�<���>��0E���Q�;C�5�K�MI��4<R������`�����#�]l��]�-��{V�?�x$�������4���$���7 ���/)��
:3���}~�*Qq�3����!!	}BU8�� ���i�_�R����L�Q�`;jX�� �����#�O�J����iNT��j���r��<���)�������:a�b��@G���_M W(�
1@�1;��@�����`�Ltk�,a�q��7q��V�:��!9���+�\��CV(-CU���aJ��#��v��w���Z��Y>�xm���R�����������0�%��
'H�'h2h��>�:�/�F�EK#����,'6Gc����7����V��5a{��z�v4�9�c��B��!i�s2���z�W�@��a	�B�Ae�@-�-xTfB��-T 0�*=`��+]��si�C�G0O�9 N���*b�p'��x�S:u�`��������A�?�"��f�|�@+Y�������X9����WGk�\�*�X��E�g&�4!���\f[^3�����z��]f���,��5WkmR�?�&����*���6*)���� ��k�o��Gp{�hF�����~	zWW�.B��������>��jf�j���s�1����x�$s���[6�����o��\<��c
������`��O���#��d�y�k*(�P��)�a��=�3���v��Sn#*Gh���:���#���8��kn�fwF�1��&�xPf)9�������sl�{��Ssp��,c���I8�;.���.4��Fcm58��mf���m}������?�	G��(8�����sjPvp��_�t��
�Y�lw4���)���5w�/1AGOT+fZ���m�pH���
,�;�����=<�>����g�C��C�PX����:����dI����:��u8�P#��;}�D��rHE��1�	�x�������~o���U��@���D����0*�a���b�T1�5`�D����
��NP��k�LT���=��e:�G��?l�|�}@^m�>���P�q�����i�J-������h�w��f��hYCKa_Z!dmv����gphM���D�W;
����W��~�y���+@���^]B�_�:���R�C��|5��b�
��V##��������r�����z���C������+�B��Y�������S�������w]�����,�r���5*|D����|UK�*T<���U0{{HQ����C�&bF�X;�4��#a�#_ls��:G����^\~��������N��V�=�6Wr�D�{{�@-����(1|,{�����E[(�u�c'���"Pj�L�a����+��b�=����HF�k*�[��a�
=`���q_�bw�>��5V8z������3����}<�q�3Cjo�ni{�z��m�(}���w���tiUp7*j� !�n61�[���%���/��\�7S[{�����^�5o:����i�H���i+���H�M�)G$�C�����=��0$���Bywu���1#��<��GD<�������9�)��X�<y����;mG�E�o��,�9"�L�}'P�����\_
��������
*.�����\��0u-�|T�mS���)r�k���0��0������+�E[�1i������H� �hf����������`v�6�b��o�?������� �)q����.���
���#q	-�	7m&��.�v�����4������u�D�'�=����2�$&����Z1vEm�{�U���������c4�U��9�n�RM*��N�}~]�5�.���K~E'G��H��`�Ex�F���B�Y�vQ:3a��5[�V���/��	z���X��b.��O[Q��(/�P�r#B����~GBb���N��e�Q�\���&����+U��6���?����<����h%c�e �X�/��}� ��;Y���)02��cQ�:��z�g	W0��K����I)���
��aI#�{mruj�2�MQk4�'���HX9���;�n1�!�`��1+�'��.�����/kJC����"��4�OF`5M���%�]y~��!��������Te�7!��$8	)�{��e������a������D�9�^���{���|���o���\�6~'+�b�4o�2��g5������G47�#"�`��+6.=r��i�����ht��u�7����r�J��V����q�-��H�L����F��)�5�9�5�}u����,�qKK�{��$��&��*��G�B�E~2�1/'���]��=�t�����4�V��7SnOIB���(e0�d
����f�o��yAc~�Hn������`�6Zq��A����ZB�5��z;��%^�4G���JT
��-s=�����=����*lD-W�J��g��_?��������R�f��%~w6�|N��	��+��VXH�.�V��������S������n8���<�6�ii�%���fP
_ ��T���u|>��}����E��l�G�8����������	�N��TiZ��.��F�j��s+s�\�/B/[���������q��`�x6N�`�N�����J;R��MI~�"�v�g��	\���T#��
���Ly$�N#Gp@�xP;b�����W��;��d���G�;�N�'������:���^�u*
e����wv:���`�|��tg��3/H�<���(�����G���zzT�����]�����T����P���tL��8�-fc�Z��{x����P$�K�����)g��7~���`���f�8����)����p8��k��x����5 �Y-<� ��j����������O�pJ�+[gS��K�2�f��m4$�CQ�;��
rtAL�Y}��
=����w�x9(!
o�W$��#���SY��r���d�>�eOqo@x��'���,�{&Z1a����{xt�cOx�[���BC��o�t�v��Yw���rhrs��;��PD3LP��������[������%6Qh��cb)�@<��j�[#������JK#yA@&x�q��"��F�qb��=�%��T�g2�QY�`t��a&i�sM��4�Mn�"���)����������Y(xFT>�E�O������=�||t@S���������~���u����Y^����[����*C���{�������W�a�\��
�z������������]��~!Q�_{x�B1��%�6��{e���R�)�%Z����
'�r�E<Q�Z���skY.|TD��=�����	=����5�Z�����?g2�J2��c9��1�OAiMfH�lZ#C*����6�����n$4����4��$�h��=P<V�oT��hAvT2����Wk�����)��#@�5�$�C���GW��p(�0G(;����qR�QX�����[������1��y���`�60_�5*�nUqV\u��<������l9��c�6e0�^�$P���V���1db9����h��6$��h�V��k����y9�+��q�|����zGtiJ��JD�����5�����4��M��gn�/�,�"�������2?��)�L��3��U>�m)����<�q	3]	�s�	����f8������p:�XbAV�P:1�R��qu�+2<6'�FM�������4"�����9qM���@%=������gar���}�z�?TQ�KZ`�-�3����m}�[�9!�1�1��)A�Q
]aEG��d�4��Q�3������i1�p���zT�Tu��R�
��>�Y��GT��o����'H&��|�xb_%�V����v�o46����z������S��`;*lC�g��&�e4`j�����#�����:�����\
����T#��������{�����3Q�j)��:�r��;2������W�������c������X�Z;;��C� X�T�x��fB�dxT��
�������1��x�]��T��JG�gN�F��	��o������J���k�Q������������\�:a?�_1���|����vv'���D^�����F�����dt/^�����HO�_u� ���_��M���%�8�w)���tg{�G���)P�W	�}8
@a��8�2
Xk;{���+y��<bn�&7�L�i���_��t8b5�m�e�.����N�
'A���[�����u�����R�S��_��ax�/��o;�WG�6��1'�z+�����e������/�u��3d����LF������qa-�G�Fg���LQf&��r��q<e������p�M��/l�A�������_`������}�}:�z�����{��m0���@W�k��P��]:����?������=�%�tqr���e����Ts�������Z��~p������U�[M�5��9GM�d��V#%J�2��Zv�����'�h
<��-'�7X�w�>�C����4�!�����;.V�0�_�!V�����.	��aU~�N{8�Yn�O*�������BZv�X���Q���}`���3������_X���cf�����8���
;VM��=05�����P�.��`��u@��`1L�d\N���EW����������C�h��Ip��A�:��Sh�W�<�)��r����C'�������	d��� p�0�9�l����J�0i��U;jm#�Q��{�����r���uj�Z��_�4y�/����K���,c@�j�Q}��������"�?v^n;���*.���&c4
w�_X�%v���M�����9rD�<.*aJ�.S��t���[���?Tq2��5fXS����'�����d+��]��+�e�TfFUp��{���u������V��j��������%��C'������
�j�_���{���������F�v�S�x]������V������8�F�W_��:�{,�����q�n�^���#0���A�[{���g������Us�������Ioa�.,1����������
��W��?���8��f�����=c��GogW��F)=P�(������PJ�B~����5��E�QO)�.DF�(;>���<>D������,��<{K'��FO����t��U�1Aey�nF�)s5VH������)�>j��j�n4���v�gb@q��@	�%����<N�h���N��Xh�|�y�y�|���^l??����=��F����BA�%�g	k�lwND�v��h�~�<fk��xKm��b����>��8��U�h���a���k��B�QA�o��?zrL��������G�&���t�N�?U��'���k��O�H0�[|�C8������p0�h���d<�I�X����!�^,�����1��`��>���
���HX��ht��|,D;��U�
LGy��u�>��0�R�v��{�.��b��3�������E�-���0�Y/�c��|�c�t6f�I���Tp��N�)�L$�F�G����NS?t�`����*�*t����<�>z��<R�p����w��dJ��)A��������E�p���)�oaZd�~0�����k����`�4F|�
�:��Qx0-;
/D��*�%]^N���E��Avgd0�YFa�O����)�9���XAfc
��!`�/YO	���dwX�?�d4���T��>���j.���,�n]M��q�lL5�B:%��t�E��A8[���8�P�S�t�]<���-�LnD�I���q�c>�6dv������dve�(�S1���a1YeV^��V�OY�f��5�����Q2<\�<ch��������R�� >%�9� [����K-�+�k�ZR^`2a���0���(;�GpN#,2P)���������b<��v���,Q1�#c�S5i*k=Wd�b�U�B�����l�h���2�fLX��</������C�{����1D��1.��:�����5�O�0F�@M��,�����$bk����b��v��}V,��Jko����nOg�$T3�F"�z�^�2�������x���������I4��A��}1���c0��;��uy5}�Y`|�
F����j���O��:��7t��K\��VR�����M��G���A�3���:����
�5%S1��k3sna�r"iGr��X7e!�������f���V����R2k����]0�����*�������+�M�
�]8�=M�"�M�,$�-��%�FL�����>K�N�4i+}z��D���{G�?����Z(��9�W*���j3l�w����{�4�p9�sV�B�zB�f�<��+@V<
 Kw�Z�
Kp�T�i��*�k��Y���q~�� \�9@����+�@Q9c\�`���.�v��@�V���
�-�����;FR�����`�Iy�����@%D�H�ag��OV�����9���3���dvY�n��GoC��lA<��(8x����"��X&0	���/c���F�=�G��K.
���k�|�c%83Ji�Bd�|������Uc�����W�?F�K�E�������+�A��&��_KoE��1�`����\���
�3v��!;w��Z���%���`�PJ��@�!gB��.$���!�����r�p	��e!�����������0����0d�f��{�m~�����A�V�D���S�E���`���d�Zr<���?��$ ]��:0�.�u�dY��KK��|��-���_���k	��Xck$���5��VW}$���H��Y��\��������Kt:��;\��x�r�������{�	����:�'
����U!?f�~���P���
���~~
o))j`����0%��g��n��ouoJ�	��C�
<Z��D��Y��������\��U�����0U,0^����[G����2����B\t�e(�<���g7n1�p��T����t;���D��P!�����P�G*$�=����*�)s�)+Df��V*�����jk]Zf��JV�u���*�flEd�nGd�Z8%V	��eB�JLk�i���Z!��k�j��j��*�3���,�E8���8���n7��5��
H�6�&�
���\���w"�m����nI,=��kO�-�Q����L)PF�\(\������q����U�����
�����W�$�#�&���5{	$�P����w����rX������({���������l4�g�� �f����(/�<��)���;�g���6#O,u~�Ah����S�����U['k;���V25�-�f�h	��7�_t~���k�������������*��������O���:K��u��
���m	�n4�G]W���kA`'\��G,(��a��3������b[�����Qt�F�)�{��OY%�|��������������fQv���`a
-Sf��th�W�>](S�S<�e�(��g`��Y�h���oV�+!���m���[ �M�,U\f�x��eJT�Gl���I�7��0�a�#��}��<�����$���z�(������hx���MC1`��"����m���6����Mf�yx��"���F���~��&��!J������t:�<����.������4|���~�{��^�����/���O���B�7����.��/��\��)��e	������&���O�S��g���*@��$*��Y�{+P���p)&e5���������K��%� o���`-E����P����1�l��D�a8������S-��a$�Z�(���"@�yO�u�{� �N��[��$���u�C�J��Y�7m��
#!_K6E�B1�Wy���7
;����((q����R|4&\
wWG���]����uT�n	-�8��
�����+�����k�VJ+6`S$Y�,�*���������:?�o�.��)�D�����Az3���X��0�	X�P����V��C]n��Wf>;Cm1��:�����%�W���g@�;=� S���.����bf��/3FQ3�`����&(i@m�B���Kj[l"#�2Al[Gntd������4.@)P������Pb���Ps���	�T�Et����!�J�[00��G����=��\1�#�3��S�Q��	\��oYg���X��N�����4j��Bqi%�$���c�����nM�`�+����axk����V#�����q�~��h<������;DCU�R�����fd�C!*��85�����[�<^��>���o���%j���������Q��n0
�W�L�J�Y@��Ga����%$��Xb���PzK��q����u�~����nx=�g&����(�NBv������!���`i%�E��2]�.�����2�'O��h<[����/^*��%��������XV��n�2t�x{����
o�_G��[jR3�p��������g�h�����`�v�_����_o�8\���w��x������]�av�F���?��y9�9v1���!����+3��)H����0�f�Pp���3,���^�>��)�w�����R���X�N��O�*����c�4���&����1O��b���k�f&m��������G�oqw��Je��c���S����m�Y�P�����P��o� �|x����a�;�a�e3�-C�
��B��h�%��C�RT�{oI�i�4���Ai������QO�z�{��M���.�M�sH��H�v�E�����������Q��8d�..�lTp�c�q�Z�h�{8��w�@�(����YkR����5tCW��<P�,(�-������o���e�4�mo<��}KT�tBUB�e�L���vJ��-��F����:�kq�R%�������L�T��G_��< ��r�n6����l�)�#��AG@��Ep��9�o��`���J���7'��oVN
��\���O��O��,X6P��R�w�jM�	��:�E����I�-�6`R���pwj#v\�f�S�r#��+�99��9[�,9��k2��27�n6Z���0��
��5Z��|C
�Z��FPS�i����1Y�oI��F@�yJ�w�.�V�o"r���	_�`�WZ-}:����#.�Z��������xcK^���'] d�n���P�[j�m4�ag�;����$_������Z=/�����M�<�-
����/BH���@��`�vf�x�s8`;��]u��V�����^0�/����c�����!����-��-�e������st48v}�-��%,��m��MJ������5
��;
�.�qnt>	��f�sS��E�d��nQN������2Pv�����y%oc5����K���JN��~-BW������X9�����������B@3_��f
���c��iZ��}�63�-g_���D����
��W8@D�J��+���R�J���J���S8�Z�����:6BF�#6����*�Z.�����%�P��K�.���Mp�7�]���l��v���.��`:��>�E�
�?�4�?+��A&y�g���W�[�E�W���.7�5�����-ti�{�\�P��q�<ife�+�v����m2���<�4��n�������h-���xh�J� �=�X��������b.AdT)��N�8�Y�:G��/�X�R7�]������L�!��Oa�]��MOaLs4c~nz�x�������h���O.�:Ey2�nTP��E��k�a����^��^���k�*W_+'��x�p=$M����D�x�P����Jj1Z
k��d�E�g1s���Y+y%:I���H�;�����B����L
�,��r�������c�[�(#@1P��|���@l(���m��I�������wy��P��5�0t�	 �d��8��3����o�����S��Y`:V�qv�����z>"�/'1�|��
�Bk����H��oz���~����U�|�������ej�)i��6���Q��a�(�4Y
�'#��LH��	O�������~�����(X��	)���(����M����������.���s���g
���v��.q������(&�w&p)x-wi�������H
S[��P��L��w.|1��H������h/����\j^[��\����V�I�	�+��9�F������u{���{����TI�U��~r��D�6^�]��[$�\�{�=��E�&���*�D����q
�O�1n2��� &�.� �~�	��0kL���7���p|>���<�.]�O�7N�/��(�9��P�������R�����k���~x#~A��i� H(��s@��E�'R���^
�}~�xy��vm��
�y��*�)]�X7�U���Et��$���,��J����v�����/���._Wj�k��ox�_C?����/����_`�F�����c����aT�/l�$*��U�$���x#Hh�^����(+o����������6��YncU��[
�3�[�f�r�	�Ql�/�6.�qXI�����Y�x�X��;m�[���+�&�P����K����GK�����,�5�N�K�{`�"1����!��Pz���r����STf$}V4}�iZ>3>	���*]r���[/|�6?���������E!kf����w�v�����N�uGt�;�?����V���	�u�
�/�R	�8�jF��y���p2���g�a7�gD�7e\>[Y��)����tM�����������w��a��k�I6�:���yX)�c����������2�@�y�b���=r
q�>�^������w�(^���m:F�z���F�&Bd'��jn�U�T������#��e!�����{�����L���F�����n�|'=�
xp�C��0�7��b�|�����qT�|�Vs���V��#��������pR���5;�~6�,3)Auad�R��l^�Ai���l~c��u���(e*��}J�<�a������y�>w��#�c
|pDa8g���\P������L,h\I ����NE��~��(�BO��/����2:�Q���`�{K�[�x����e�$~W/o��xx]!�0�CJ�#h�����IR��O���o�Fm���6U��7'�,I�C~�6�� <]k<�5���=��/������|����d�J()�=
�y-{��B�;����=E0E�����[�Z���U��*A&;��x��Z)��R'��F���+�Vk�A����z���@��Vg��xB1����,���Xw=��)��)?d���m3����Yd������&�b����g�y	pW;�O�==�'��j"�����"]�uK[�m"�	K�c�����]����>yz�'�+D�L����������[�3���Nw��Wu���V�]#���hzB%�����mX6`��:/%\���-
�|1:7%�p0�����������e���#z��f�|u���@/"�����N�!*<w���q����Sv����-�R��-�Z��?��8�c���}�%�DP+Xd�a����s����edK{jA��jq'��{����U��\Z0���r���E�}Gl���?�����_������n!�N���V��B��E�����k������;t8�����rg2���;a��g@��S���5�����U���
���
��@m'A/A��}!
���k^�������xSK{����K�����S2��i������3���X#�����1������3\_*���e�&�M	L4��n���o�|W�Y0�M	���J����J�/���=�6-_�i#1��L�0i];	n>9�z���������V��'5�}���2R���m��u�^<).���n��J@�h�7����JM��DSu�������<Q���L=�h���#h��J5���G�P�����p�gx:	��kR����X)���g�Bh3��9�t�}]�'��~���y�rx}� �/r5&j�PED
..�!D�����{�m�F�1��z�����?�RT8�/���G��}5mz�A�6�p6�p��e��u�����Q{���e�����q�
���F\*�"���xr���W�I����b�qw������QyJ�����2�S�����`&�M/���l�fTm�-���V;Ni	\:��]
�	��!����'[���� �����K#O���}�����|q5�a�����
��i�������K��gD@�_�����Oi�&5d�Ty�(@�^���HD�=S���
b�C��&��I�-��^70	/��B����L��3�6.��"Je����6f	������L� ���~L����D�.��6�5�~Rm�n���������q���_�ZUp-kO��@�V��
���uxh��Hl����L�t���kg��j+��vj����j�	�vC4����G���1��_�:�	LOLw���6�l<��#6�W �(J�J��I����$�����ZP@��eW��t����z��fLk8�>y�C��T��o0��1����|#�:�AJ���6-�[�9�D�6�E�y�����e:�2���L�_��/������N���,���&d�w0��G/��:4�
����=`.T/�P���E�-~~"��#�w3���U�-w�f�u+k�~~�5�|�v��p����:�v�9����;p������s �}��1�1V�7�!dr���h�����2��)���K�o����_O����_Rp��������-j���zM�ln��c���j�@-��j�XpvVN����(n6����j+���E�����/�v|o<zR���F�
�����H�;�K����ip������������]�z�%��Y|zuyI��~_<���M_|C��}u�1��GM�,��fX)f��v���fD�pfd�?�w�(������2�3���:1��[T'R��{���6���K
4���
4���_U����S�c�y-����Y����L���qP��t��O5,�M5�7����������R�n�������.������Z,�W�*~T���}\�o�H�0'#��\�a8�����
�s��d�'�b�b���:�mKH��Y��nx�k���wS�2O��$��v���������T?���������C���aw$��B���W���h�����g28����_b��T�����@������'�P�T��2tGU��f�I;����7#�����4��Xb7p���i����w���d��F�o�W#�����z����O�t�������i�����U�����4?��<�i���_����}t���K�X#����Wx��-�u���������N1{��
���
�Wk��|{�&^5�b�Y�-c��X[�$$�3�33�����������ar��t�D�E6���h��"�������_�����Oz���?]r�&��e�_�^&�;X��KP�,AM����UI1���Kh�@^�=}P=����%��ke�&v��L�����#�����,Bv+���5���4�=�������
���9�>���w���8d�+�=2�Tx�7,dn�����}��z:�]��ms�C���=���E�&�.
.��I�����VM>��������������~�O��E���N\���/�������8��l0��>���c��X5���|m�3X������M��Bq5���oF�-��,,��.	y���	~:�������4'D�e'�_9��!��u����(O�t��<���wRn��,XbT�����gg�^?�H�h:�=�����Ix7C<
�/���!O����x��9
?����`��q?�j���n?���5i�O����`c}���<����C��|�(��D$�<�_�|�e�����v�%;�g���/^���/��s�"E��`Qq�[[��zvw��7�0�;�(u&��n����@-�-y�B��3�G����Q�t	�h�.����L���by�H5TXrt��C(���t@bTUYH�o�8���PS^������^<E� l
I���u�������N�)Qn>8z���B���j$���������w���H���`��p0
��#�L?�
	����]�=[)�")0~�����y��s��Ih��� g|��&P^��@���L�����Q@��m�r�������NH��Q��������{t��W
-&^z�%���=��^�!c�n;arVy�������cp1�C�!��.���vG�oos�p��v���G�f�q�H�]l�W���0xd��\�u���i'�b_T����F���T��o����x�����K��Gp��������a�Z��A�����Tk�\ra�[Y5�ap5
3�x����bQ�,��o�"(����VF3���tvlN^\�9�
�������[���,N���[#Il�9��9�~SHW0������h���=�1��?yI>��Y���I��aJ�,�t�l�x�������[<��8������Xq����@p��\ <�Kj^pw�~+FY��la 	�PR�,������/��r����`������x��< ��9����QlwX��8<��l�}�������N���0��
�|�o9�LK��c6���N���Oku�0�.ql��������o�%+���e5�C����p�%�|R��|^�Y09������U
��jX:�yd�
cO	��FW!5��9����������o;��F9��hQ��D0�
�|(���j����L�����	����U�D��,V��]���C��R�~������a3���+��=���1���<w�
�s�],�~�6�t���*D��M4�%�d���z�����n�����"��
{NIx�����`D�c�����v:�G�l������3������8�|��{�G�q� 6���@����1b����p8~O���t~�K�ON��{�,��:��H@KQh��6f���`��{W�>����	m*]�-5��`��������	h��A���yZt�����S#�L��ew����[,vn��sax��������z��|��C�3�R�X���_�T��/��5�GG����H���^�����G��>���"����d�����DJ
�E[�$�NNE
[�y��eBV[��	&{�Au���*��_K|�Nl��;k��5��C�nx H�{r�h�#eHW����������y8����4��i�Y#~�\C���G"nw�
���>8����Y���'��tEQ�.���eR�s����A&�ii������S|_���Q[\S��=4�����@�l�[���
\�y�}�^[0��[�����ih�-�<��I�
���W�G�8^���/���m���d��Z����n��S��C�iz������#������=6ID���s��2}Di�����"�����_�_�_���V!;�{�v�v���_���zO��}p��{nz-9e���a~+�G����7Z����E'~A�,T��������r�\���l<�T�	(�k{?�|j{l�9Z����E�|4?|OO�F�q���J�5>|O����|S9����
<M�O>�g~����|z��Py�����dR6����������H9-���M������8�I�)��+��KW��e�+e��bB�! �a,?$�� !GA��4�oX2kQ/R��:dWQ�0���80��L�����2`(�2����.b��+��/!L$�����x���>U����g^��_�>�Z���w
y�9��'���5�z�p�7p���s{(f6P-���3�N���H�AiX���j���`����I���bJy�	����yE~~��9�Tx��t���b����J����#W�E����s���]T����p���`*�fE�b
�����v$Bg4*U$���<�_���u����m8�V�1�`��`���[�v4���G��aa�:g�`hj��r����Jq&��d�@�!��|�"?a�	���?����C��]3���G�4�y����h���aU�QyaT���W�^���NY����-9,s`�cVec3�����Z@���	��!�|����#����$��>�������!��E�I'�s��	���N��������,�'1&��S�
�����G{?	./������1�����C���������	��M��"���nU�5s.�H��F�������#:��
���d^��Q�YqC�����ZN��d��� .c��A�r���q���my~�����E�h�"��v����������B��~�OG�����uw��1����6���:�����k�5�����Db]��D��y�9u��nG`Zxc[>�;�i��W��t�n���4���"���q�Vg�I��Qz��k��C�����������gm������I������`=3X_���B��/)�����k��Z����Z�P�*��
��Bi(�e_�z���;Q
�I�O�� 7��	&�4���#���� |�������)���F<
���KX�/�SV�:��=���xW��J["�\��)l�����'���y��conok$��^O��f�j�#e���H@���t�F�JH3%�Q]��>�h[Dc���R���B`����(����S?P�;`���()6}�F�<�ur��\U~U��5F�c��|��B����#����n9�����$�Jz�Q��|��pG�6�e�b����#����O%�Y~������j��XP���}q?�e��E-�b��;��`wr$�D����\�����9��pNV��9�Z��_��4�����:�������Y]:X���qT5����!c;��}��-L����`z��s7���lBf|���E���;k����x4�M�H��s�G��������P�X�P����:@S�.|A$��d-�4�M��u������������;;?��=d+����Ri�	�����r�f@�d������-�V���r��S�]q �'E��G9�tU����p�e��#T������K��"��������u�X'[7���a�
�G���� 3�[-F�q�2�6y(��2�����H|i�D���w�7~�]���;I���;�Fhp��&�����A`�������H��nA@�xE�������D$R%�R��.��38���9	�n�|T�������L-|-�39K�����F���d�n���d�PU���Q���I�Y���|��*A�����aEN�AA���T�t**�kJ�KS\��H}a�f����d�
1���.��xf�4�V��Z+��Bg�U��kk�{	5�+�u�T���e�`t6�\��9���A��R���?v:�P���������C�M���r�p���0�:H������5f�8h+r��a�8���:.�`A�����cSA|�����.p��&|D������6��A�;����p8�W�7�f�I?<#ll����y@M)�IxN�t�2��{�P�:�*���������e)�������
O{�����f�QcOK��`LK��{/6��fq%d�y0����]�
�"�uPi�j�w�-��[�o������!oN�9�"�7�|f�#�*�K�#���riX�����k�V]�>�5��em�.k����`�U�C�q��<���>����/�g�e�o��j�,7��9o\���9��3�v���J�l<^6�vZ���y���������&���?�������Pk���9�����E��aO�!������/��>����"�r���Y�������{*�:������g���o4Zgg^�+���������X��w}��m�*�CL�!\7���rb�l7V����qID��uS���2��R���|��h79��<W*(�^E�����K�W���R�J���uu�]['U�'��r6_04���e��T�gqKO���*0��r���b���.�
���"o?��A�D���
���(s�������5�O(�������U���&���Ch6]��h�b���E��}����Q��g�8����a@��`o��
w�h�����~��9)����??���|_����o�~�i��|Tv7�"�g�R��8�{���"�`sb�-�	I0��r�-�C����U�b[ew�����$�;kOO%dN]��u�*���B����{Sp)
*���
�C�-�A��������iw��O���XDf4������o-�u��h���)e����|��.��i�B�j�������E_������h��hz��� _��^~b� ��4�b�uS�;�6:�~
��Vj��@�y��\��V
�<���f��"��+M�N����$����n��E�R������k������ER�$�����j����V7M%��I@F�j����(�]��u!�`�����a�%��H�x���
X���{Yr�}�&�Ml�
��i&���
��ifYP����`�ASu5P�P$u�y�"I@H���_�eR�b���l�B��f�lIX�����{N$�������g��Bu�����uuQ��:P�+>��"pTJ?�����0$�~(�Y�`�}
?\7�M�|��=�8z�0@���Z�T���\]��ntI��5��B�~���_*m�����*a�]���"�9H��N/��g�����-�lQ�1X$�E�Wky�)��,L�^�;}��|[�u����`�0��\"���z��M���@��p{��nhD�����"�XktKx"4��3�U@���hH���c3/�y��iG��_X�yJLA)	i���>���On�����s?cFg����0�:9JR=�[�6�.F,��f�vD��O9M��	d�K�ZxS����8r���vhi[QD{:2��E���ez�k{M��y����,Ns��WF&����/;y�Bn�qf2�_���y�zd��l?BcP[�����*v��r}6��+��0&:B��Z�	�P����}Eh9��p���Z@����W�5� ����(O��Vk�����[�D��UA�N��o�M�q�j(��Z]/�GWl�-y���H,����~KV�D���[���U|H��$�c2&�!�i����p������G�}~��S)�jtu�i��{�,��x}��yZ�-�`�!�����*�"G��2?'������LA�� ���D�~��#�����.4��mw��
������l}����wa�X1-@��,�Zd��<�]v����'��_��~�1�o3���B���V�D�l_�UozueL���a��)	����������������������z~l�����!��i��pi&Sswssw��s�OF�����(!��H\r�g�E�W��8f�#n����p5�Fw�/�I��l�a'm�6��VW:z�&���qV�X>G���Q^�d>s]���9��-~���3�e?�A��X{h��t����bL$!v\T�����3F�lt3G���zU�X��Y�!M���T���������������;L�<^�'n�c����[��
>��+�r�h��A{�S���Gjo��I�r���kh4�WO� �����?`���~������r7������a}R��� ����o�\l��<��D���L�"��Q�wN�L�����.�����(-yux�����d���7NmZ�ai�Ji��7G�������Q��&.R��6��JL%�L#Z~Q�~�c����G2�iJ1S����z�u�����^R�>e���*����'�h���(~0���x,w���x���o��[�,��k)>������Xs>�?�=6����i����>���+��F�q���J�5>|O����|s9����
�S0�a�X���o������������H&e���Om�$n&�RN��?�_�J��XSE����^�Po!)]���a�d�j������3�����6j4	�������(H�R�>�"%)66�C&��"�d"���(���iW���_y�Mzn�����?����7��
G�������H�kR��x���r5��kx���A�K�����k�����.X����P�z6P-����y�?1|,�jP����t��4{�$���$�L�����X�O��+~��c�������rxt@K�	��W��v
����Bh7{t�X��������+��T�m<�R;������5��YP#��(�PX�>'�0��o���\����T8�^���u6��
����������������H�D�\M��V�f��FB��`b�(b�$0���}�s�Ds@u^���Y��|�'?Wb�3��J�}q�t���q��r��b�"8u#��"���HM�z��sd����5�S(ns�]�]���	47D}s�����M~�$�Iu����&mg�x&��K�����d���f��6*�h������	k!)1����{�BS8B��"{l!�%�X�go�_��$��'�?���	W_ks�{6���<���v��0�1\��7�<����o�I��z��WG��F]����}����9�f�G��o�f�XPs�k9a��y��_��.~mG3�����j���=���W�s�M���i�E������������bP]!����wl���.9���������Z�vm��6�x|%��=���<�� P@���0'��-�����M��`:K��kW��_�D�|�S�!J`_l�0?��E����^�����x�R�0�����Rr��%XO���z������X������|O�R��T`-L�@X-�	(mJ[��V��������~�7ZO��x�g��iH
Cyd���W��-�W����� 5:Vp��/]6��Q�_���h�~Q�J�1��&�����>+m��Y�?���$��>����.fw���������'��*i������b	-J[U+!��jFv�V�P����/nK5c(�
�AO�F�p:+��l�@�\H��!�OnkJ�KL+	����o����J�����hp`MrG��"_(�<)���m!���W�CJo?�������f� �L�?��@lrr|������I��J�O�T|B�Q�j������vXy��)XL^3�P��Kj�����Z�e
�s��U]Pq	����#��������J$WG��3U\�.V��:���R��Tl�}%?�C�)t��Xn��|��������	�^h2����M2D{�Y��H����lB�z�}?���E�@>�S&�J!������_h����/��g.s}��q
��N��w����=X�������P�d����j�JM$Kf�R�o5�C:R%��������]&,�kl�vB�)�������!N��0���e��#T�����;M��"��������c�C4/��7D�w��kfQ��HI"���a���� ������ ����Ek�6�����uGc����}����<;�GAw���Uw8�5���X';�(��#���y�>���#���!Y"9����,���jJ*�V����.���R���,�n�|T������%M-|-�3O��H�2s,,+�lt/B�#��iKT]��$�d��%b���
��`W��nrU�8��R8��T����N�I3"�@���#'$��X$CS��j�T��R�*�/s�L�,9�T�Vs��2��Bg�Y�sk�{	5��J�Z�I�i�J������9y{q�6��'��N���E���T�������2xNG�EH^���!����k������TQ���(�YV�����p�����*R1�a:���:��XR�~b���~3I�3��b]�VP{����Ng�����pv
����������A���-�@0�M��a#��&O,�rJ�4	����N��B�'v��E�
nw��spD�
�o[��C]T�����V����)��MhV��y7�"��)7E�Z�%t�y0����"3Z�."k�Mc�4�����������h�'������<S�=�J����as���;����\�,�m����U���/�������s�5��{v��*�
�8���Gu|Pzd����4^7���~5�����7��i���4=
OW�<�M!���t����fZ�1���Ors,=F�o������"j��SZ Lg�x�B ��?��:���/|Q#W#q��}��;:}E�	ao�,���g�"��%����p�
C����8b]�����2�U�S������\�n���c�a��$������.��)���u:��^������}:����c�W�$��(2�s��:�}�"{)����_
}�����3�������?��%����&�U�)@s���U�=��E�iW
�������H�9��b4����U����J���(O�'S�j�Fa���xLf�`��~x)6�\Ej��H��"��2TPwN����������yl6���VS��J	s��t'�,���^m�T��~����bY�]��w�<\�P��V\A��j����e����U`�ET+�]��g��l�;}��Q��"�^�����z�Q�V[]SY
.�7��P1UE�XY�����^g��HL�n]�:��~�oc�������W����>���tLU��-������&��E)�Sa�mI9�R�</�E�p�rfUR������	�tj��)�!������i��*|$���f���L>T�u��l�'Q��u�M�.$��Y��)IVkV��I�45)�.��8#�����E�����>-���0� ��UA���U(6��
Ib��!vb����"��������S�F9�$G�$�;���f\��1vd4:U^
]�BF������8Vk�c-W8o������N�1�87W=
9L���F�[�vTn���i�t|��<����������-������i�������8�����
&��=����P9�)S��4;��QL%�dZ�'������O�����4F��D�\�������a��	��?���4f�(�.[�aW��,Z��s��dR������zF\��~!����5����[��F��4��Q��j/d��M���?���<�/��6"����
i�
z��"��xB}G	5��K�p;e���#� �K��)��}����]��of�TnZ�� �~8�I����3�3�(��%V!>��+�:��\���8�����N�h�k�]{�
_��Gx{
���������k>���JF������.x��Wk��Z��3bNg���)>�j4���D�F�N���9�sW�`3�l�����1��v�A����&���8�,��9e�?�rv�Ye�I���q,	����	ij��'O�W�6����k����URmm�j������~������:|
�^�J��������R��R`V���J��\?�:��{��CWg(-ii����i+pn+n���SWX`m�g���j��Ep>�4��nZ��� ��"-���ya�c���_�Kt�_}H��iem}*��y�[
�D��>~�����C�m>t<�CZ����t���h5��MRm�Wk1
�V���!��FX���U�e8dNV�j9�p��\�M��)yH��N�����$�@��MO �r�4�tI[��:i%���a������%��}�)��^
��R%���5�&�"�������(�4yO=���5l8�3<����5)� T��b�Ao�����8��!^&3�X�A"��]Lgrm�s��eI7���0\E"�����B~?�k3��	O�p�����k>863�����^�
��
��C���M��I�a�������XYG"��2��qT�d�GV�Z����g�yzw�G_NN��h0���H���������n����Y��N��1	1`YQ	��,.�Y�<�L�}X�����S���r�����g�������w�}���dL�Yr������!S ?t����*��;���S���w����6���ZSy���?���"6FF�P�y�������=8��5����Nj���yn�>��>��S�O��c�[k�
R��k^3b{����Fc<�q1^~�B��`LnN{�p�t�a�2I�l�=�O*e���
���<%~~�EP���J����0P�L&7�<g1�gW����.(-�4�T�����b��h���I��sQ�
6���-C#�'��{#��FXHm����������}$�ou$��G�]UO�����r �l0!dD�&��X�g����~�����z��=�#�I��Yk�QQ�l���.�c�����Z�T�����
L)��8[����4g�\��]��C��L�y����v�����G�7���^0���i������F S�:K�R���@�{���3Q��n���/�/v��������j��.�S�$��(�iz7f��4��)*s�H���b���N�^]^�'�x9
b��7&D�����:tv�����|h}>���-�w�����<�� T��D�� t�z]��)��" ;,*
�]+�oy��N�4f$�2��)�t	�Q��-�/qh����u%��)��
 �	��@�@+�.dVc3=�����,9�?`�<���`3g�T�?iw������JU��u?��QS��s�!*�,]�]]�#X�r�	G�p����>��?������afr@��*]�:�����EV��.Xfgz�]������X��������$�@���<	��������
>�����f�'�;��������]z<Bb(����w��*���`E�nl ���2�P�P�4���g}U%Bu����xR����I��D���5�_\���YX#\���$A�`q��Q,���%�e��4�^�oa���r����&^
2��>�[���/��[8�LJ�8�V��Jn�Y��t
�Oni����QF	D����D��6C�l�Uo,}���,:k�m�p�!g�b��l^;rz!l~ ���x�ul$O0�/��):�����h���8�)��%��1zJ���<�+wR(l%_z��_�Qj��T���yR��L:�R��`��lA���D�^c��������Q���W{-��%E�J�$�H� ��q�{�,����$�b;F������s�"���w��7��C+�;�������l�?o��&2���������u���8���98X+6�e[b)t���������;{G	���r�<G�<�%������v~���_��-��l�]	��8@�v��V��r��i{���$�C�`k����U� ��~#\&�����,�Z=��{~�q�2�~�c���#Z���-��)���7iZ73N�SO������������4�%�JV�n��t� �����������+ju��b��%��������"��������}�8�������&��<�@s���l���n�������}�d�G�\{�yQ�;��Qc��.R���������#���7�q����\��EXM�B�8���VG�nIrDf� y�u�����	�l�.3;���UzcL�3�J"�2]���lX��N?���0��M��h3����v��n�\o6J��w��-r��]����9��7�������?�q�dbU����T�NsQRB)��H������"Rm��7o44��Jd�e1�e�����H��p4���J���l1c�t���aCoN�2\�y���"�.h���+w
�N9:�I����)�����O����5~�s<+�}6#���t�Mu���=�a�g}�� 5Qv
Y�����<-v�e�qC����,��Ni�Eniv����hgd��F���L|9h_�����6��]P&[�9���!�5-�����2�.%��L�Q����'.'��~K>F_U���&HW�Gc���N���\�D*#38?�[�bO�4�D�T�R�p�q�I����
��s�S�r��U$��y.���GF^�(�Gq5c���P�"�.�B��W��b����5��5��c6�$��8a�5X�x��c�m��F?����f���Tm���'u6�j\F7~�*�����Aluh��@j7)�tVu�	r0�4�2s������#�D'�q�J�5�S���
����/���2; �<��gv���g��D���LT0�����*�L��y
$��J�O�]���X\?i���Wg)vN3z�'��<%����5=X>�[x��*_��,��iJ�\���LB������m��<G�T�'�??[�wO�+���|����x�@�����\�M$G"�QX��}��(�6	��>1m���	����wT����Ph!OR�p/����G��w���-�V?�1��7����w�K�S���w'�W1���xgr	t�Z�/`Y���_�����#����t�����Z��U<n������n28���c�*k��~��OH^���"�'��/�$YKT����E7����>������
�|��B)>v����_v�R�7�pr�l��h��vv;JZ��T�����:����~���N�iEL�-�GZ���L��a�O��e�/���]��D�x����e�i��Kc��x;���G�~I�Ea�)�$���"�L}�->�X!�K3V��3L��\)�c�T�p�/j��{��W�����(2�.b�I��x�����.�o�
�b����7S���SV��w6���)^\}�PVUj�����'9L
(���	�N��L�\�1a���6���5����F�T���v�.��I���m�}6��'���
��^�)�`�K������a�F�y���03����6�o|�
���sN��o���$F�<�W�6`��l��L.cO&c�~���Ag��C~�������w��=�>\l�O�%�H�h
�;����.���(k'����'�@����������Wf�<�	;�6��:h�s��%�N�<����l�I.m��B\��0���E���-��tf��H!��DE��%��<
���(���������)��O8�9N<C�%����������H�����>?����U6������XWq��V�cq�Y=��M�Wf��������j��
�p=�v	�������X������	�3	k'��IJ���'g��o����F�$���@SN�:����L��4�����2��H����ABe��&�P���`��
�}�1�����������j'�d�D�@��D�0��v�>lX�(j��hde�	���q���V�M����n1"E��vd�Y_�ydu����	��E��O��'��Orj�}����#��>��/��Rd������/3�q�k��?�&�W��&�d��kg�dY'�<�KL���b����4]g�*�8~
�N��d����i%���a���WC:,=Rf������0z��4>*uQ*�0���l�?���A��@����
�$:��3]XBB�|Y���K������X���y0��$c3,cP�Ol��7I��3��8���$v����T\]oZs�(�=d��r�q�Cvj!�Z�4��nm�Fu������ku
��s�@�=6��.B�����[�K�n���eR�L���,_7��r���P�LC*i�^�i�d
��*m�&!�����/:��;LO���Le:�������b��b�+�G�E�2����W��CJ�d��a7\|s"��MR���?�p+���g@��2H{	5����r��>�=���7k�J����<����H2��i
���R�_J�s1����Q��c�TP��_��Qx����
%x����w�_l�{�5^ �i=%���J��(,uT�����Q����1��W� ��x�_y�?���Q�>�S5|����zlz�{����-��c���AJ����������|@I��:yH��og��vRf���%�)��������1)��?R���'%��F�2)~bR>�f���',��L���������$W�����b��t�n����s�s��)�,�H){k������n"��S
�m����h���cj��}1��&���D���D���D��1��/�#���G���b�4�X'��I
-���l�4�Z���4��b����)�N�;�H�;�D�;%�����N�b��t�t����(��M�9Y"�����V�'�5>������OnM���0!��f��H@4G�����0����f+����r �9����7��D�Y�N����w������e��`Lh1��&@6�!���E>�.��
u������5������gQG���gq����|��Af���[�����<b��!�T20&P����n���4�	��B\Q�i�r�e�M�Dd��h@�����0�D�I��x������;ma`�/�����
����.cN���V�L�������3R��f$x4������$<����#�7�D���i�m�����P��`��I��
���h~������v��N�T�U7|�}G�xm�T���l�i8�F��
���K"��������W�Y8�i"���z7���G���Ep9������;~@��(����goi��������� qO	^'C&��vI��_g�������Sd43��fo��U�T<P����>�K��J���������fJ������+�e�lc�l���hl��[�,Y��HZ������Cm)h������f�!vX��r��R�T:���#���gJ�����`�h�����b0��^��
Y}���#��}b�������g���~(��uf�}hg�����M��G���#����YF4�e�Z�vXm�	����t0��_��S�w�������xY6�F7��C��T��)��,�8�]1��.��������d@�X�Dm\�,��z��9�Z�@+�*��,�J�{	i}�r�|�9��R�
f&����[e,_�KW�0��5i�>NTdU2Qe�W�����O�ZC�6Z�W3�o��h�w�����"������Z��z"F����kT��SB�kt�������TZ-�(��9!�U>���������'�����_�����\�x�L~)Vd6&�	'�����������j�����c)W���Qz�J���$�Y�,+��6��L)�����pZi*'��Y��8�����gr)�rw����Z�u�J��@mY�&����2���,H��;i.�o@�Ei�B�l�
E����4�z�R
��6eWc����6����r���T��x��Y��;q������sd���tR�����E��0�����lZ���J.����s'+ju�� Cy��|'�����1�����R2��F����B�&���n2���v�!��o��w�d��5����^����nOV��x�`Rpu^B����y5�F�V�k��U.n+'w�������F3B�4'*��~V{V�����K�����.��X(3����h5#�-sG,����'���V8Or����7���vm��W��|#_RMz�fS����5A�a�(�+^sn�~��s�n�
a���.����Y).5���-J$��i�����z*��:�
�H�������A
�wt����K+	1���Kx�\�B&
U�����b,��!����!�so��p��T:r�5��E�Z@O��N�6���5:����<r9�������a�,�5W%O�zV'xo@po�������Z��9a�*��0�&����h�F�9_A,�5	�:��7@�sk�N=�h��B,���Q0�!����'�?�.]��
;����.��k���i(v�F[���
_MH���|@?��*��G���D�
��"_9Wa�2���GJ�]�����o5(/_SF�f/���7Z�B�))],H�
+L8�����-3��3P��2�������2e�u���W��|��"w�?����*���U��?(�O�z���b���fhtM�$�!�����-�:�S�J6~��q0�vi5��G�j&h���,����-�w��H
�H�#��=Q��s�X�L�rjK&�f&���fa�T�p�&U����������t��tKC�N�eil5���������`��"�
z$�L��i�]Sn����'�����XW��lQ6q��{�XcS3���-��_�a:~�y�����j1����-��A-L$"��q�%��j�,
����Q�k"��bqh��v/��v5z?	./!�|F��pXd<�Bx~u���>X<ADv�3���.�����,^��X�FZ5����E�m����j����`�	��H7�
�g�h:��Hw<���>���r�,el�L,�/�5��7O���_R�	}��	/�4��w�"S��$��p�{C�-�i�l6��z�;[h��%c�E0�����#pj(.h7��Np�y��I��u��P����JC�M�zJ�0`���.�������>�p��<#]C��3i�F�8���hy���<��S��[y��h��Z!KY��'��$�d����r��������lfcJ��[i�
��	��/�n��=TTT��0���W��s������8�@�*��G�
F*D&���rHGSMg��!���G�I�6Z����H-�D�w*RpP��r�NYRo5�5��X�F�T:����@����X�����(+������
:S2�����hG@��\����n�6�7&��LM���������������O��c'�*��T���_��=bNz������,v�;��8���SX2���;N�����Q��Ky+A���(�*���*?��*_�T���l�I��t����sC��J�����������	]d�������
V��@��?�����Aj��g�6���7o8�d/Dj�p;4�Z'���o��j�1T.x1�T����#�����;�B]#1������t�����?A�������O���)��apNJ��OI��Sr��2-e��2��p6��1��U�r���B�����VK�n�K�|�=�������bE�D����n/B��l����^��Q�~�~qQ���R�����@���Ho��U���YY�,PnK<3L�h��@n��-�~Rm�n���r��?n��KWD}ku�(s���aNH6R#�f��@Y��x��j���l����&-*���&�����. ���_0c/�JCZe'Z;;7S��$el�����������2����/��9���Yp5���o��/����H��Z��������@���Qc�U���}����:���l��������0�nt���B���`2�BG����7�p�3�����jn�/��{��j�[��]m�^�4�[���c��Z:P���Z%����"f(g���f���Xm�j\\4�1���^<����o���8����a�������G�?�yN38�8O3�r� ���|_�=���#'�����u��U3�d����KI�Iy��Z��UkQ��6����i�������."-U����J[�(�B�
�{_�]���
'=��I����0��6oMe�O���/<���<I*�[�>�L��=���l�1���4��E�VD���������lM�9Q��6�������b��eIL�����1���p������o�<�����E���u\���_���#X����
�Mk���Zf-�������'=kg�G��1)�'���/���K���^Xo�B�|�2���;V9_��)������I����t
����3��
h�id��5~���(2^=�l4����
�Fh�[2�A�BS
,%+����9�������[K~[5�x1A�H���"��WU����7}F��o?�8V:���lA"c��(2NE&�L�Ie�����R�.2�WHj���l9�F���We��wt�nxX6�]x��������Nr����[	��v���_�yw�R������`3�9��V�(7w����Ma��p���������N�iy��������m�:M��x���Yx=�W�{3�|U��r����"K�-/�B4�$G�;d�t�r�{����P��{?����W�*��*ZX�:���L?X�	��Y�����7}^>��>�����$��b��B��J!+#O��S[��Q�,�b�:6�Rv����3�Y�0�@iD�V>��[}��bke�&�����v����=�o�M�����H�������"�!:�W���0`<�}H��a�|�(M�t��o��'8%<��45��Cn���NE��z��jf��[m�Z�
� 1g�Z:��h��c%(�Q��R��Uv��S�F&���8���x`�_�_���5>D��8aE�3'��(33�d�YJ���
��<S�Z� /l�i����|���#�\��4�n�\.+��b5�ls��8���IuRaG���^��9�Ra�B1�!gz������V�������~KV��j��'��/��
K�S�(��Z������5)�\M+��@�mS�eh��Z�����Z)X�/P�����n�2lvG�y���R����,��,��U��gChr��� y�Ai���l'����*�� �b�?��p���
{N�Y��f�,�{	������s��.�9�lu������{�{�N)Y��1��|�v.4xo����%�"R�3�L�m�0\f��E�& �a�\�29��/HS��2���B7Q��/�ZU<x+K������
�^�:�}m�P���pUD��R��������A����T`)������q���U���n�xS"%�z��%L$5U�r�'�M�������(awZ�;��!�"�@R�d�k��Q���<�>?�I���#�/O��Z
��f
.q�v[�m�c��2)C�qRA7T��$����W��X�#��S�9(���jvy5s@?�F�U`��2�@��S��xM$j6ujZA��y��o���/��]0������u��wm�F�)I?F-��u�����G����W�:�U���������������Skol���^Kj�2��!��!��w���BP��Y��l!���%��R�8v_\V�.-=�)�1-��%Pd��^�M/�^)��j�D�! H�MuI~H��� Io<������QA��%�0xQG������=�'�O�DAQ~��y�gI99�D�����+Z�H�BB�#!�3��2���yE~~��9\ ��w�_l���Zb>��/w�B�h^UP�f�3�8����~w�x��n�6x7O���t�L��[��A�'���#6,��$W����0���{\,�5(�}�Z;S���
�p��b-��3������
\������5�(a���X��Ci}A��.[$2�?R��h�����7���T�?����k ]�Y6,�k@T����>�,�[--�������|���EZ-�>�����������!�$Y�Z��������:'x���8�l�i���vx���������]6Yk�Vk���n*y���'QP�������"��xc����iBB�~8����V�
AO������:Q$�$��'}�aC��&���\n����#�3hY ����Ff��`�5�����
����xl� 0��<eUR:Z_
���,��;�+�1�w�����-\�G���conok$~6A�rQHS�o�@'�E�(�����(��WnH�I^��S!��:�M���J���E��Fd�$t�x���\��:�������c�+<b������y-����7'�n�C���j}Z������n��4\���������*�CV�.���H�9��;��"s{��t6�r1��Bn��C���)v�R���C�**X�u��(>��M��yP/�>�p��w����=�}v~���D�U�{������Ri���qk���uH�����#�P�WP��K�I0��RZqR�'=��������e��#T����m}A��"��������:I���k}�5C����4�0���b���'��cZCS&�eZug�����N�R���q�,����&�"�5�`t6�\nr:��/�/�B����AGu���"$/v��e�-�&����y8;��r�����I8�+l����l����_�'f�����IxN2�"���������o���L��e���W���p�QC%(�L���U]�kS�}P}v��*M
���xT�U���3���b:���)E��r��I�����]%(��A���"���L�s�[���w�,`r����aO*��-�(	�3���^���\���!���6{A����K8d��5�f�4����&�I�_�S�l����no���+�P|�����Z2��@������D��;�WV>��9k��k�nc���j\�+D������$�x�F9�mx�����5�v������HtV��d|���3�����O��S<��	������U������{]��<'�����y;G]2j�����Sw��y�.k0�����X5����-�� 8�l.������SA���vX��3\�nM�n��H���.����i%a:Y
��^����$�@U�x�x��� �k�X��e���{X!8w��������XHs��>�"0�<z����,}���YV��fQ��Qu~��U�����\�����,Lr��S"C��K������s�.��*��vhE:4��9:"������^��`�<N��I&���4����m��s��8(�i��4�����}���kR)���T�l�e����8�
������E*�s��25B������+��A�f��C�A����f�Tbm�e�H	.�F�brO��n�Q��)a%I��"�5#S��f*f��ew�����<R�9d���-
m�B���u��3�_g�]��07�l!�nE6�f:�	��
dA�T9���
J�x��*Q�>.�0R�1��&�E�s1�����]��0M����'a��:'�E��.��d���P����Z3��QT5O�<�L� ����SR��o9�c�oH���)8���������~k=_^��51���/14��Wij��5�����=���V��{��y!�t�1b������&���+�������7jcv�����pH��u��+�ar&�U�0=��ae��Z��������������|�y������RH��*����]Kv��d�Q�\9zm����������������B��Hg�V�zj�^�d���po�:�Y���������L�u������R�PX���`�n�`�b��1��s����K�u��-��Z-3lz��������`����������c��`V���Ex�)�s'�M�/3lw����{�
�-�V]0%O=v������ 6��)bSV��ByD0;K�R(��c[x%KIk��?Sl��S�p�\�b�����5A�B*��xMT�'_l&-�fuR�����)c�5����.(il��Yc�w�6�������.$ql(w�9�{��c<o��;By_3��O�>��4��l�LsK
����V���V���O[����6W�WS�BI^���K�j�+��4��)]s�5����t��5�S�Jg����V5���P��s���|9Z��]EvQYZ�@M����;Ok*�D��/���5Y�%9���{ZVke������T�N���BjW�����p��q������sj�`���%+�j��yZMs����=�kj5�d�� RR����w�R4�kz��������������\3�&Eu����������0-���_�_���f���v�	`��`��,l7W��]$������4������������L������\�2�0�Vf
0S6�$�y����cx���_�AF��"R�&gG�����Ia�NYa����I�u��M����������s7�_�.�_���3�k&Ek�n��]vt���1�7���~�|��;N8���q�[ ����W�RZ�YK�������u3�����J<�]l�����@���H>���U�~6�&%��b\�`8�*+&S@�RB)�
��(���$W�0[�1��+��v���xU�@P�[�
Q�$Y}�e6&��.���4���a��o�^@�^yg����<����B�amQ�\�Y���N@��+J-�Mqs`�M,���$�K��X�co=����6���V��tLr���XKl��Q����5^^f������m���d0�� 0��8U�gF�o�P�I���z��h���Z�^aj������5��2�}pd�A��V
XE<Jf�c%������I��&��V�J5�J�*)XR��1b�d���d�$�Le���t ��5CA+�es3�����Y^��/��:0>Z-��������q���xr<:��;.//��pK�����+�����>��n���U��O{��R�a�9��)�n0���KN�2'W#�����}N{�eHS����mH������Z����Q�AN����W��i�6����U=���N�`��6�����oZ�����F|���K�uZm�A*�����ZM1{���AG������)���U<Ny��#����G,�B�6��H�+�t�	�t�U�|mc� �l�P��E�8�+�������+�t:�b�_8
���	,=�<���C������C��eC����mb4(�[Ul���j�5�~>��}���i�m�jZ��$��G�����PD��f�M����X4��
	��*���lcz|99����&���Kq�z�ow���h����F�����I1�c%��6�}�iU��aF5�Zj��g�1z�.�w{��"?p�;����8���aX�l\N���7;�x'5r9�h���J�C�kV�9�����(|���#���!��J�L&78/����]M��I�t�f�E�:{�����[r6��u�{'Aj�.-o��<�h��FT�5�mk���6��
D�fg2�N�2�yx6"���!����Z���QR#pKR�����pHT�7EM���k���S�����oh�ix����G<}l|���d,�WbIW�T*\S0��Pn�z�����3x������w�~�~���T<�e��1���BCL�&���������]���{&��N���n
�����)��eh�WJ�5����oBA�v��^�mD��uC��:�CYDj4�v�d�
�Y����}��V�0?v6W�r.|I��q�9�m��%_|+Z^0��g(k(�b�A���`)��|W|�6<0���eT���,��	78�X��W)�j�R�@n	�v[�����AJ�%��Ur�,�Y��Rl�T<Zq���R#�S���`a@-�[
IZ��,���eW���y����!�P"��>qp�����]�E�fBb������huvf�
�_A8m�3������o��;RX��Q��8D�����U��5tD�
U�g����Ne�G<�P*l��S�S�c.��@�������,�������*�����-�p���������+6S�4�f*����P�&;�T&/Lw���v�R-��R3������|����|�M�4��������>���a�	=�F"��pS�
}����iY1���|�MX�:�9*Y���W'��,��B��t���#E%�d�e,�^������X�!�t����H,�,"��J��}����mW�	���D �zxsP�?��p���?�jm��'Bg}1x��-�O��m�YhilO��GX��u����A2v/G\H�d�fo��+�j�%���;::U������Y���v�2�����	f���;��6b�{ETi��[iK�&&MV6&$e��	]����+��������w���M��I��>��8������*��\!2��7���9R���V{w���[����>|�k36���d�lK�9aBD�$t3�������I9r'��iv�V����� ��I���t.�[����������*��|�cvO{��G2s�������wS.�
�������������B����	�����q+�DnEs��[���0�9`e�<���a�m��)f�l��c17�D�@%��
��;
�Z�w�,?�����TCq��1 ��d�H�#�����{&����#�w�h�4�L�*��Q�#"�����
�����'� H^=G���-l�r�yh�n�5�UM�u���	�������KcAD�(<�^rO2�e������[qDPh����'��#{�x��N���%EF����~`���s�t��w����$rg��EF�n9����"����|��������k`)�|@�r�Og��>Em��B���d,�}��>0�^��}�U.�o+��`��
O(��g���~h���p�&��N2���g��tSg����?��-��ejN{�r��Tu�P,
��������'��)�|�3R�[�������_��������5�&7M{�.}��oT�h���Z���9{��\ ~�����z�p#.I�������rv_��p;�w�a,'��_���M��%�l	B��/\#�E��D��&��LgLd�[�����(��<��2��X��q����:�D<�������x��:�
�?���O_��d�^%bIV�V�y����C����~l�X2���8+��o8�L0ORpV4���#(���.6�@�[TU�^�7����L��m1��:���q'�����.,�%�=��"�B�W�T%���������`o+�D����r�Ij�jJ	p�n<�'
�>�-2I�8��
]��7�
p���L|O6\^5����W��� �?�B\u��([��C�O:]���^r�U ����	���n|��|hV*���f���C�B�(1D!4������
M�����B��-���~�=�k;q�� ���1k�g�-�*�Au�\�%��;4���6x
������mc�>H�w�)8��>&�I�h=��+1Z��yi�
���V��(5�C�>�:���v��}�������n�.e������j��	�u@Q.z�9���C���Q'ALB�S|���5����*���0IO�+�U������zU�W�W��_S)��
0002-JSON_TABLE-v42.patch.gzapplication/gzip; name=0002-JSON_TABLE-v42.patch.gzDownload
0003-JSON_TABLE-PLAN-DEFAULT-clause-v42.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v42.patch.gzDownload
�E�^0003-JSON_TABLE-PLAN-DEFAULT-clause-v42.patch�\�r����M=�W��
n�,Y�,��reJ���J�R,%� ���r����`����sU�������2�����8l����a�4�fo������7���5�t�����=��[��}'�}�j���D��2����b�|tBS���?�z��x��q������7���^�_������ZL�vM]���*��}�����j��j�����m+|-��>���":��_����p:9}{9���Cq>xw��r",�\��^�^�s�j>��t����j�����W0�j�_��!��i}�W�����A�����n��2����j^'�������N��N�:�hS'�6���e:��~`���\6�rE$��XD������x����v<2�6`�t�u��A���M�sg��S����~��v+_/u�+���]�>%f�l�D��������#���q��<�_���;��^IA�NRT\'3]���:�vs��n;�w`
���5
�q��p0��\�/&7K��r�?�<�)��irH��4�D�������n���^������������,���q�@X���������pV����VA�Z��^_�m���zeoo�,�^�qBa6����by{�l�j��F�mX}a�Z�n�U!�=�g1��~u�gtj}Q��C��FW��t?Y�����\���4�W���Fsi������g�9S�[.Q�O`���M��	P9����~8������z�J��D���KT�����#/�O�b8�@iW&��MjPz6�������j�A��e�q�4I��=x���[�p���o�����R��am���v��y���'�����@@h��-{.fO�A��=�Qp��
�	,��}�u���=g�CO�L�f(n�����^�D��'o
V��P���6v�:��ODG�DJQ�����{�~NxK5���������[��;�qlZ��zZ��M�i��4�fh6�������y�dj��	E�Y<�d����@�����	+J(6�!�����\@���qS�u��!���\�%�"
)�ct�&�K}������������_����n��XI}ip�X�e���-�p&�H���M��q�0@=��s�D�S�#	^�M�M�zu1��HH#&�S���`>B�9���@��Hf��+�,x��.?��z�Y���h.`d�V��e;Bj�	e���R����d|�Y���I���I���k��$P�K'@!6�F����;3'�����w�p�
�����x������9��(���4S+�P�^�A���p�T3Zx>`�Ub�����}H �1NdA��8��'�����&�HS��3�H�9������n���e1WB��L��/E�{^�`{��vm�������x2t�Vv��JR��*��>���$f�#��G��L���%7�M�`��N��m\A1]�S;<|~�lg�?N�|`��~��S���G�,7]��%���6�q�fUdt/�I�A&$f��N�Sd�U$I���(��)���Em�	imX&�� ���4��"G����3�%�(�x��0�C\I�cZ��,h� �Y�Uy���;s��5!����Jq&��z+�V���5�t'Rc�N�7N�@7���Ue�:�ED���7��-@���� 
�]�?����-����+-����R����&E5�QT�P�)C�FIy����R�g�}6�P�~M��]���
'L�D�������]Mp7��*<�"���\��)���I|��Hy�o��g�L���S���M�Q�����r��Wk��h6y!��YK�P��v&P�r�'q�(4���Y�5	o�j���k/��m�j��hY���r���Rd�P��7�'���'�Kb?r���ls��������n4Z�mZ#�;��oRnn��zu\@�s��)6���	��L���>�W����(�]]�1^���.��e���QN����y~n��:&v�r�����t$�������L���E��jh��J�������A�gx`�v_r������>=��&�u�xH�;/�C�C��_ar��LJ�����~c��H"a�Y���������V�I���������Z>8������)qj��s��4���1������=�c���S�D�=%�����
	x0���������=�����t4(�a�N�"WnDcN�4 s�$0YP�����y��@�2)�]Q���.���L���d1�������(��`m����y�h��w�no�F��Z���!#�Uh��q��</VO�_M���>����$����\����2���$*��b8�2������q�b4�ua�`�"�87�#Ba�&�`f��>#������`��B��z	���?���F���z]s�u
E����m����'������s������<����TS��tm�T�����Av�-�[��%����xr������^������re��K�V��Ip,z�w�m4:�Y{ft�����F�tPn�0�n�;�`�\���m�����s����B�6}�
�+si��%^VxE��
kr����7,��1+��!OJ%���W�G{����)o�Na�"��y�w#76��Nj��vj�z��[/[9���O	�[Z���	}^�yw$4�sjg��y�x�^g�
O=�'
��p�Gg���.#��5X��F���^^L�W�_�1ngL�yScz��~�f�����X��A����Y\�>���#<�-A�pzy9��2����\�^�s���O�c������H�gTzy:������?@9�A.IS������hp6�Y���X��8�
�s ������#"0�����..?���
}!c�u�Q��������[����@fx���5��
��������yY~�x������H��*�}������5��eE��IB[[ ���%����oU?a~�U���W�]'��7�����G+Y���X�;����J9]�w�k����2T�w�!Wl*�����ak[���N������� H���/$%b����U���0[)��iV����.pB�1��q���Q�_���)�K��h�S�<��������Y �Ml��� ���Q7N[���������xY{I�Eak��'�pn��s��/"��	���QZw��|M�K��)��g �DnS}�9����Z��Oi�6l�[R�6<����t�-w4�|
1L��`U��L�ot
2�������^�6$^��|��~z����2i�0*E'�H���T)�'���}Pjk������'f���t�;lF����no��mMH��
s�lS^�C~�����A����
���Ah��>��*k�W������D��x�whU�1�7��1,���N���E���|^�V��<��[�%�?�������+/Vj��:�B��%tp�.�,������,e���Ll�D�
j;�t+�@���BT���x%���}�U*���+RmE�
�r�8K���XDF��V|���l��H����U��H�D�H�����6�#Q��R�8����h������XkN�����X�I>�����v�f�+�B 6K��a��LO��~�=%e��O����BVV|P�B#��-L���H�QOQ��i��]�&�yrJ�g�83����5�.?�V�"�=h'��6Z�������7�|uFG���R��M����6,�At�J�=(%�{Y�����V����P����U��
��Yw��E�9�<�spP�/�jM��S���m�`��|����E8Bf�������g_;�1q�hKk��pf��6�����s���G�����^����n�d|?�u����h��������bJ�_��L�7'�!w1�
��N-s5��� �s3\/�e���b�@�W�u|,�N�[\�����.R_���}W�>�Rs~o�,��6.�d.�����������(��8[��^�G��t���T�Ys��#n��q�$gX�
Q�������G�Q���F]��T1�WH���a����y��������
��RVv����K�N
��� ��l���5]��V���*�jK%�	9�B|(t�������""�����%����e����F�1U��{��'���|�V�j�
�h���%{GZ�
!�+���q��2��T_%��u'J~����V�lT�g���'�=��s�Z�m�2�[�,y������RE��Gh�R9��,�@n��<`����1;����j3��� #��8N��5
�U���i�^Ug:E��y�Ns���'P��������5�B�Y�����H��N��0����g����<��?Dd�#S����
��������E���e�W������1��Vx����QH�e����N�9]p��Ky��!��/�t�:0�q�LRxP�?8��*����������~��=H�|�  F�C1Bj�V�
��nA��I�E�T
� �����	
��L��rPI�3�&�uJh��yw
%�9+��y�1���$]��Rt�;�%���1�&o, �M��!;��@yT��K���\Sr�����v0�h��l��4�hBqs�Sra�V��"��sq��P�B�+��)����8�I��]�C���%N<0��y���6	Vw�\I�5P%� �	����A����DR$�������m�f|��(�����D7D��K��/��5o"�
�=�����yb����6e�{S��)�+V6���Y�����~+[F(��
�3ll�o���,�"r���Z�^6$�&���c�{Y���������'�~{���#�
%"��6KV��f��o����3� ��j�A��{x�'y���A���D�/�_'���v��NPjb��I4��no�tX��.;~�O�%��c.�(A,�k5ks�P4m��d�7L�qo��L��/��
����Z~�/s��#�����Q��pc�U��a������(��i�(��7�UW}�3��+���L�54�<�D>��<	�r�8*�����0`����u;�����������{���#
&���^ ;	���F#3c��A�P��5�i�R�.���C�4U�GR�E���/�n5;�]�����o9�i�s���?���j��lPO����/��w8��
U7����"����BU���9�z��J`�G�.Rn�[��p�F��It�������=��jm��g�pn�:���������s>�M;�z;:�ju�;tP%_�����A}�#^�����|�kE;a�"ap�=`�������������6h;�?xD?}w5z:��K&Q��{s�y|�������&��e�C��NO���.��k�����Z$J^H�R��pug������)�1���P�Z=�C�����UD�b$���"��t8:PkWj"�B�G��J���8������Y{�=u�����c� e
��a�J�~ro�� �+J���*J�hI����d���bx>N�r&�<I���_��w��Y�Ir�:^i�eD �����Qc3}3|�,�oZ�uvZ)g����y)^�X����wW�/��_/j����]3*/�@�P�4���G����F�Q�q|��������#��+�r_c����������.�FS�GiA��-����)��`4���f|�����mi���=4�V�������V���
$b��_Zj�;K�4�������h��(,U�EGr�Z�oA��?�	oJ�:��J���/k;��Z���������K�y�b�^����y�<�{)D���
��#��B�/v�B��5*<�����Q� ���WZ��z`��h���a^�<�������4�H�z���)�Bb��8��X�4{D	��C�c�%T��8Iw.�q�A�E��9�}�����%�m���fS"���������b�����+e\jh��lK(3��r��Q��S��N����h��@��O
�o
��~r�DN�H?���_~�<��^������#v�f���i��]\��gi�U��F��������w��m�@�s�+�($]R/���a����J���1F��dm�7�V���t'Y�%��G^(S�qQ�dUzt�X:����]�a��.� � ��
��S;?'�`k; �R����{y��	:����a���;y�������w��SP��I��&k.�j�@C�
D��i������UhQ���*V�]V 7v����� �����d{�u""GR�"����oq���_�1V��V��n�'/d��5m�}(#?�G������25za+X�+�����J�q��bro�$W
@�RrHD���79�MT��?������W}����h8��|�F|�|����D5%0��b$	\pl���}�|�h��35��RS�G>��'o31A]L`kJ	
ki-�Q��}�+��v�4=bkt
�)~T���%~RG�V��GP���Zx�
u�A�d�=;z�i��XH����7V8K�q��R����9��kV�������:�/�!�En�0hAR���{�A1q�t��4���+ZWLF������x�B����Xg�x�I.�^��t����������k�u!l�������C��
{��������|~`a*)P�J����u���&����.�V�@�g�8�Pv/���&U���������Y����;�$�'Ow�A�`.~S��p����B*��8f8n]9��Z%�*�����7Kl
2���K��4�B�$����u`
I�Z��_���9��$���a�Ex����R��K�e��U+
gY-JPS��*�T�L��T��Jg\�e�=v���t@�Z�]�����)SK���"K����r[���-WV�	�F�`�������f��L�|w�m�2�'� �L1r�0N@�N&'oN!�������F4�;x.ec��� E|�&<�7&��f��d
^��t����n��z�y~�~�q�Im#R�����a����9�KN�d���QI?���#�juMKx�S�P�K�K���* �(h���]0U�"�i���v�k�*����]"����)��4MR��3�Y��Q��^��n�b
S������������7�}o���n���������W�(g7%�p�� ��0�;R�WVRpsUb�S�}��
��#������*>VY�\��yz�R<�3��;FKo�����
�`�j����
0004-JSON_TABLE-PLAN-clause-v42.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v42.patch.gzDownload
#34Pavel Stehule
pavel.stehule@gmail.com
In reply to: Nikita Glukhov (#33)
Re: SQL/JSON: JSON_TABLE

Hi

I read this patch

There are some typo in doc

*name* *type* EXISTS [ PATH *json_path_specification* ]

*Gerenates* a column and inserts a boolean item into each row of this
column.

Is good to allow repeat examples from documentation - so documentation
should to contains a INSERT with JSON, query and result.

JSON_TABLE is pretty complex function, probably the most complex function
what I know, so I propose to divide documentation to two parts - basic
advanced. The basic should to coverage the work with missing or error
values (with examples), and explain what are wrappers. Advanced part should
to describe work with plans. I afraid so lot of smaller examples has to be
necessary. Personally I propose postpone 0003 and 0004 patches to some next
releases. This is extra functionality and not well used and documented in
other RDBMS (depends on your capacity) - there is problem only in well
documentation - because this feature is not almost used in projects, the
small differences from standard or other RDBMS can be fixed later (like we
fixed XMLTABLE last year).

The documentation is good enough for initial commit - but should be
significantly enhanced before release.

I did some small performance tests - and parsing json with result cca 25000
rows needs 150 ms. It is great time.

My previous objections was solved.

The patches was applied cleanly. The compilation is without any issues and
warnings.
There are enough regress tests, and check-world was passed without problem.
Source code is readable, and well formatted.

I checked standard and checked conformance with other RDBMS.

I will mark this patch - JSON_TABLE implementation as ready for commiter.
The documentation should be enhanced - more examples, more simple examples
are necessary.

Regards

Thank you for your great, complex and hard work

It will be great feature

Pavel

út 14. 1. 2020 v 16:26 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

Show quoted text

Attached 42th version of the patches rebased onto current master.

Changes from the previous version:
* added EXISTS PATH columns
* added DEFAULT clause for FORMAT JSON columns
* added implicit FORMAT JSON for columns of json[b], array and composite types

On 21.11.2019 19:51, Pavel Stehule wrote:

čt 21. 11. 2019 v 17:31 odesílatel Nikita Glukhov <n.gluhov@postgrespro.ru>
napsal:

On 17.11.2019 13:35, Pavel Stehule wrote:
I found:

a) Oracle & MySQL (Oracle) supports EXISTS clause, this implementation not.
I think should be useful support this clause too.

SELECT * FROM JSON_TABLE('...', '...' COLUMNS x INT EXISTS PATH ...

EXISTS PATH clause can be emulated with jsonpath EXISTS() predicate:

=# SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a bool PATH 'exists($.a)',
b bool PATH 'exists($.b)'
));
a | b
---+---
t | f
(1 row)

But this works as expected only in lax mode. In strict mode EXISTS() returns
Unknown that transformed into SQL NULL:

=# SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a bool PATH 'strict exists($.a)',
b bool PATH 'strict exists($.b)'
));
a | b
---+---
t |
(1 row)

There is no easy way to return false without external COALESCE(),
DEFAULT false ON ERROR also does not help.

So, I think it's worth to add EXISTS PATH clause to our implementation.

There is a question how to map boolean result to other data types.

Now, boolean result can be used in JSON_TABLE columns of bool, int4, text,
json[b], and other types which have CAST from bool:

SELECT *
FROM JSON_TABLE('{"a": 1}', '$'
COLUMNS (
a int PATH 'exists($.a)',
b text PATH 'exists($.b)'
));
a | b
---+-------
1 | false
(1 row)

EXISTS PATH columns were added. Only column types having CASTS

from boolean type are accepted.

Example:

SELECT *
FROM JSON_TABLE(
'{"foo": "bar"}', '$'
COLUMNS (
foo_exists boolean EXISTS PATH '$.foo',
foo int EXISTS,
err text EXISTS PATH '$ / 0' TRUE ON ERROR
)
);

foo_exists | foo | err
------------+-----+------
t | 1 | true
(1 row)

b) When searched value is not scalar, then it returns null. This behave can be

suppressed by clause FORMAT Json. I found a different behave, and maybe I found
a bug. On MySQL this clause is by default for JSON values (what has sense).

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON EMPTY
)
) AS tt;

It returns null, although it should to return [1,2].

Yes, regular (non-formatted) JSON_TABLE columns can accept only scalar values.
Otherwise an error is thrown, which can be caught by ON ERROR clause. This
behavior is specified by the standard.

FORMAT JSON is not implicitly added for json[b] columns now. The current SQL
standard does not have any json data types, so I think we can add implicit
FORMAT JSON for json[b] typed-columns. But I'm a bit afraid that different
behavior can be standardized after introduction of json data types in SQL.

There is another bug maybe. Although there is DEFAULT clause. It returns NULL.

ON ERROR should be used if "not a scalar" error needs to be caught:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.a' DEFAULT '{"x": 333}' ON ERROR
)
) AS tt;

aj
------------
{"x": 333}
(1 row)

ON EMPTY catches only empty-result case (for example, non-existent path in
lax mode):

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS(
aj JSON PATH '$.foo' DEFAULT '{"x": 333}' ON EMPTY
)
) AS tt;
aj
------------
{"x": 333}
(1 row)

I got correct result when I used FORMAT JSON clause.
I think it should be default behave for json and jsonb columns.

I agree that FORMAT JSON could be implicit for json[b] columns. But I think
there could be one minor problem if we want to verify that returned value is
scalar.

Without FORMAT JSON this is verified by the underlying JSON_VALUE expression:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS (
aj JSON PATH 'lax $.a' ERROR ON ERROR
)
) AS tt;
ERROR: JSON path expression in JSON_VALUE should return singleton scalar item

(This error message with the reference to implicit JSON_VALUE needs to be fixed.)

But with FORMAT JSON we need to construct complex jsonpath with a filter and
override ON EMPTY behavior:

SELECT *
FROM
JSON_TABLE(
'[{"a":[1,2]}]',
'$[*]'
COLUMNS (
aj JSON FORMAT JSON
-- strict mode is mandatory to prevent array unwrapping
PATH 'strict $.a ? (@.type() != "array" && @.type() != "object")'
ERROR ON EMPTY ERROR ON ERROR
)
) AS tt;
ERROR: no SQL/JSON item

please, check the behave of other databases. I think so good conformance

with other RDBMS is important. More this method for checking if value is
object or not looks little bit scary.

maybe we can implement some functions like JSON_IS_OBJECT(),
JSON_IS_ARRAY(), JSON_IS_VALUE()?

More - we have this functionality already

ostgres=# select json_typeof('[10,20]');
┌─────────────┐
│ json_typeof │
╞═════════════╡
│ array │
└─────────────┘
(1 row)

Implicit FORMAT JSON is used for columns of json[b], array and composite types now.
The behavior is similar to behavior of json_populate_record().

Example:

CREATE TYPE test_record AS (foo text[], bar int);

SELECT *
FROM JSON_TABLE(
'{"foo": ["bar", 123, null]}', '$'
COLUMNS (
js json PATH '$',
jsonb_arr jsonb[] PATH '$.foo',
text_arr text[] PATH '$.foo',
int_arr int[] PATH '$.foo' DEFAULT '{}' ON ERROR,
rec test_record PATH '$'
)
);
js | jsonb_arr | text_arr | int_arr | rec
-----------------------------+----------------------+----------------+---------+---------------------
{"foo": ["bar", 123, null]} | {"\"bar\"",123,NULL} | {bar,123,NULL} | {} | ("{bar,123,NULL}",)
(1 row)

Another question - when I used FORMAT JSON clause, then I got syntax error

on DEFAULT keyword .. . Is it correct?

Why I cannot to use together FORMAT JSON and DEFAULT clauses?

JSON_TABLE columns with FORMAT JSON, like JSON_QUERY, can have only
ERROR, NULL, EMPTY ARRAY, EMPTY OBJECT behaviors.

This syntax is specified in the SQL standard:

<JSON table formatted column definition> ::=
<column name> <data type> FORMAT <JSON representation>
[ PATH <JSON table column path specification> ]
[ <JSON table formatted column wrapper behavior> WRAPPER ]
[ <JSON table formatted column quotes behavior> QUOTES [ ON SCALAR STRING ] ]
[ <JSON table formatted column empty behavior> ON EMPTY ]
[ <JSON table formatted column error behavior> ON ERROR ]

<JSON table formatted column empty behavior> ::=
ERROR
| NULL
| EMPTY ARRAY
| EMPTY OBJECT

<JSON table formatted column error behavior> ::=
ERROR
| NULL
| EMPTY ARRAY
| EMPTY OBJECT

But I also think that DEFAULT clause could be very useful in JSON_QUERY and
formatted JSON_TABLE columns.

DEFAULT clause was enabled in JSON_QUERY() and formatted JSON_TABLE columns:

SELECT *
FROM JSON_TABLE(
'{"foo": "bar"}', '$'
COLUMNS (
baz json FORMAT JSON DEFAULT '"empty"' ON EMPTY
)
);
baz
---------
"empty"
(1 row)

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#35Pavel Stehule
pavel.stehule@gmail.com
In reply to: Pavel Stehule (#34)
Re: SQL/JSON: JSON_TABLE

Hi

This patch needs rebase

Regards

Pavel

#36Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Pavel Stehule (#35)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 23.03.2020 19:24, Pavel Stehule wrote:

This patch needs rebase

Attached 43rd version of the patches based on the latest (v47) SQL/JSON
functions patches.

Nothing significant has changed from the previous version, excluding
removed support for json type.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQL-JSON-functions-v43.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v43.patch.gzDownload
0002-JSON_TABLE-v43.patch.gzapplication/gzip; name=0002-JSON_TABLE-v43.patch.gzDownload
0003-JSON_TABLE-PLAN-DEFAULT-clause-v43.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v43.patch.gzDownload
0004-JSON_TABLE-PLAN-clause-v43.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v43.patch.gzDownload
#37Justin Pryzby
pryzby@telsasoft.com
In reply to: Nikita Glukhov (#36)
Re: SQL/JSON: JSON_TABLE

On Mon, Mar 23, 2020 at 08:33:34PM +0300, Nikita Glukhov wrote:

On 23.03.2020 19:24, Pavel Stehule wrote:

This patch needs rebase

Attached 43rd version of the patches based on the latest (v47) SQL/JSON
functions patches.

It looks like this needs to be additionally rebased - I will set cfbot to
"Waiting".

--
Justin

#38Michael Paquier
michael@paquier.xyz
In reply to: Justin Pryzby (#37)
Re: SQL/JSON: JSON_TABLE

On Sun, Jul 05, 2020 at 12:15:58PM -0500, Justin Pryzby wrote:

It looks like this needs to be additionally rebased - I will set cfbot to
"Waiting".

... Something that has not happened in four weeks, so this is marked
as returned with feedback. Please feel free to resubmit once a rebase
is done.
--
Michael

#39Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Michael Paquier (#38)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 03.08.2020 10:55, Michael Paquier wrote:

On Sun, Jul 05, 2020 at 12:15:58PM -0500, Justin Pryzby wrote:

It looks like this needs to be additionally rebased - I will set cfbot to
"Waiting".

... Something that has not happened in four weeks, so this is marked
as returned with feedback. Please feel free to resubmit once a rebase
is done.
--
Michael

Atatched 44th version of the pacthes rebased onto current master
(#0001 corresponds to v51 of SQL/JSON patches).

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQL-JSON-functions-v44.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v44.patch.gzDownload
0002-JSON_TABLE-v44.patch.gzapplication/gzip; name=0002-JSON_TABLE-v44.patch.gzDownload
�_K�_0002-JSON_TABLE-v44.patch�<�W�F�?��b��_k�����u��d	��I��gG��XA�\�������3#�l;%���S��!��s������`�Z��Vkt�������G�q�����f��7N��[��m���������?����[g��9�t���b���n��#�r�����Y ����YT��x����sv�%��c��,��>o�?���b�Y�m
��nG��?�:���X���{3�]�;�.�[[�ry������:�����r?9�*6��k��s�*B��v�U��oW�[���5�5V��m1�0��;�;U;�N-�U�q�Y���`a����,$���8
B���8s@���k�����8����������@�����\�D���(5��%B�����$,�-����8�!������fm���h5���r�y��f}	rf���������2_�
�6���y.�K,�"����b���F��-�5�Wa�Ed ?�H��,�'3���D\!���
=	%����
oy��9Bf���D�r�*�>���
z����y�����o9$4�`��s}���	&����Lh��?DH
��HR[	
��vb���;]=-��[�R����sE�����3���(5���?eF��E�i�:d"������)9r]
8Z������N��V ���q�G��`����<<L���@��F�w�XTPoy�;���
�AO0{b����,�n0���7�Bq����qy���m��l	�Sm���(�lm9�x���[7bV�s����Bl�,>��e5�V�R9��f�}�H��������	J~������^	�N��:�ko�)H�Gav+��:@@�����%Jy�$�������YR0�K����^�Bzcw�!��-�UD���������
���1������h
�4�h��0�l68�.H�vL(;�JX�����'��^G`�wt��g�����<~BQ�y�*W��7��Y#�����T��z#kc+@�)���S?8l�� ���f������S�:6������w_�	_n�f�e�����<�o��:-���������GU}
?�w��z����=����VQ���W���&�����fa��b���"9�?������RzH���C)��~�V����	�{�W���Xp�#���U<(����cHRd9pgz|���
���0�QU_���[�������L�����b=
9�36G���EsT5���U5���e���`�<���3�_�f�g���b���0&�����?�%V�T���l�g���wq��r�
�J!^n�����m��B<]����;[E�w4��,`��	�S�s�s�YM����9�������R�?e�A�T5�;vm*�Qd���,��;��|�S�z�~�'�����y��s�����S�d4�:�~��91��I�����t�W0i�����|�v���%�t.:}6��H1���~�������i��s}1��u�����w�^
�����L��lSg����0���P�L��2��I~�������}��{�Kk��D|C��z>��Aj���]x;�\������_.e��;vO�<m�rz�������O�����
��O��A��������J��0���*��;tgR(���C2U��.�2Yr��O�c�#�>��GU��9Vdi���0�&�������cz%�����J�a��f[>qf�6�wh�F��Y!�|!{�
{����A�����]�����w]wb��V�L.��`L�'��pec\��j�� �
*��ue����u����@RD�]G��<�":C�fi@aQ����#�F��Y��,9]4�\�C-�Z@����k�Wq�V�^&�
�BY-�0��"Rp�u-�/H�J<b����(����=�4i�L����O�����R�0%I0������B�������q}�tu�V5�����
)�6��`���h�=�SKI./i���(8JX��je�P�X��+�L	a�������]�b�����Q%
.Qy�>�s�q�dB�j��
1��9�M��+����n�L�x�	�Q��A���\VYT		QqF��*��5	�t�x��k����Tj�d �u f4_�)��M!F�3/A���^�F-[�~��i�m�my^�������g�m	u�f����AhC((50�[�s�#��t�h'U"���VZ��;�d�7��>��S�Q��"���!W8���M�{.#��
�qNxL�^3Ep��������;����_�5N������:c���6�9����)8����J�P��Few�+"W��/� �������;��6�v���J=�`�h��>���$�L�[�G�z	q��dw��3)K
�ja���=Xs����+���TC�i���VJ��H��K\3k��kmf'�*2D	\U>�4!&������R�s�=2��y{�;�L�K^B��%��Jj�����"��V�4�!E�1�:D���,���d�1�L���K���Q3�8	��/�Bm��$���n]�D��q�c�J�@IN]�B�LCy���*���T�Qk���Q����*������Vi��ZB�z�f�����
iB�\P*�(T�*������(Wz}Pd;��{+t1���jZ`�K�
�	��r���~����62�C�%�mK���ZHZE������s6u$�a��S��%�b�H%��l9X�B���M���N	f)�S��PC;"��J��q�}����DgY�nW�+�����+���J��H8�TF-�C+���.h��YI��� ����:���9����LOQ�W�+x���o�2f��������7�����XD���S�3��HVLc�L�j��M!��$�j�L�i��hx^�����Y�J?���� �����/0�kg_z��)&uNY�^���V$(	R��������<]��d���p����0�1~s�A.��hIx������x���"Wt�v�a����]X��K�S����Q��/���f
�,������r�!�d��U��A�B&�S/oT���+��cJR82�_���!N$#IZYb�����Iw|.Ky��fh���k����Y���b~�n�S����������U���j�@�j4<��pC�:W���  ���5/�����JV� ��M�4f����X������u���q�&1P�_d�aJ{f�t,�1Z��n�&��@���/T�
!�I&�p0�A������R����q9��5u�O�S�XT��S��O0�%��!*u!��t�G�-��w~]��n7��oQR������R�k�>-Z�_Q�n��S���OA��bq������������L�,��'�'d��tPZ�J�6���6Ili������_�Y��O��������������%����z��y�����Qx���(�k��'������%��M����K���&0	ZjV��a�m]Wz�I{��)���$��0�XM{D�M����D��2�X�����:��aU�������(~��]�.����W8������*����gD�!��6����p�A%�@����09�P�r�MS,R���}�U��ko?/H,�'�'�%�3"�Im��]�^��uK�+��H"\�B��P��\�Q_��~�����Y0��Z��%b����<�$�����c}�K��8J���$��8B{2G���z�]��\,0��d�59X�����qZrQf��K.�/0�&k��A
U����z+���W�;�):�#h;-t�`����1�9Ny	5.�(���x:�����OSR>�#�2h,b��z����G+X�zy��#���������
y�,u1%-��p6AM.�fF��T�R���������z�[}���~�����#�?cw"�%�������z�
fJ/f&i"�r�x����
%zH�����<�d�u����������;p$[fy��
���s?=��b=>�#`�g#�QZ�!�����`6�>��-�T���*c�>A�����!��D��,����w..@r�u �+?��f��q��Lr�EC�~�!:�=3F_�agg�����b��E��T�y��O�#�|rJ�}2)y�DuD-w�������%��/A7;���Lw�.��������C���O�qpXi��I@�-~�s{0s��7��j?��=����x=�����w��m`B��[x�	��%��>��Qfx��
-��8����
{�v���6V��1��-�����&~�<5���UFk�'����Q�^��j
{��d��]�B>M�f=����+�"����]yH�D��^���d��;'�@%=N=����#����9�iLG`5Y#^>����/Y��q����d��V������^���SO>g*���$l����Lg��Ox�|�����o/d�Q��)�s�����OU������u�D��L�8�@���|Y��>)�����:�u#���FM��8�T����^���f�p,M�(��FC>AL��j�}���s����A}��P��|h]>��iW(�����!})$���
O�KNH������d�WVG� �11���,����q��QG�����	��+��d�S+��;����
?�<�
Y�6Wy�sHk���)����h!�m�y����O0m`�X4�V����@��)tA0o�{^����%�]��3��]��Q�������W��:��{�T����cf�Q�9�iU[�]W�d4��]F���f�Yj��v�To���+�a�Ya�>���k#C��#�}�%����r�}��;f�������w��-��}������Be��<`&�d�N���Z�R�v�i*�������	K7Z�)�"��LIrw�P�@l$�0���k�I�5[�&E�$EPg�^�����.#
�D|�v�E���7'�Kl�����.$�X"�9b�,��^9����!
�Yu�
�[��s�?��Dn�IWi�j��%�@2�l�I���K���9�d^v�9�>�G{X��D>���b�E�t����)$�
����_ 9���oP��6���%A<��O;��M����>l,M!�&Z�Fh�M!)�w)xv���2���=��y��'���.�~.�@D����['�Z�B�+�.���p"Y�$rG�����OZ��o����Wh���>�%iA������&m�(�=��TDSI���4lkU(p����\�A��Z�.���<;���wC��=����_g��>���q0�Y7�����[�tr��bg��<�Z���t�mk�l������7���3�bp�b���������)T��m����@��~r,sW���(vq��no�����9LkOx��)��_t��	�.^�����cL��7t ��L_�|K
��	���{�-5(8U�	Q��
��"{������A1c�A� 
-���0n����������,��Al��>xs�$!�s3���N=b�//��,a��c�O�����;�a4~��X����0FY�XV�3��,P�����G*���*OA��L�(���]�r���M��,��$���<Y]+GJ�+�9
���
*)���,,����yA������8t���t{�|����8��d��P���u0tF��,���=����y�r�L�GW%��x�Q�*^��WP	+��Xt���\\�����sq���{���c�����v>Ct��q��n����~!!�$���cz�������	S5��%���d������?%44�\�%�7��X_��"\�.�R�O���mu^XV5ji}��F=��Iu�wmG��W�s�1n�5�R������o�K��:��?����7��BXlZ���(2v��Br����a9(8@v<���[K�����d��fb��������%��[����)�*Q��IgL���%G6�����pv �n;��$o�����/	����g�~'���:�b���Q?}�s��Q�"g��3O���)�i���k83�a����g����&���-o��L ����H�����i\<?>o�/����D��R6UH��#���9m��-K���_^�����QR{�������~���|����%�)��%26�6�;�����
<��,��[��P�������R#(�s%�j�-��D����&�L�z���,�p�����[!���3C�q�?U:E��K.cC��#N�q�K��B�6��
��9�N=����=������H�|;�^u����Q�_o��$u�f"������XrO�pN�T\�|0B�0y>^��b�a�g��)���p-����p�2<M22���Ii9�J�DK+��S/M�@8��)�wg�Qx�dFP�������7pY�o��2�c�_j��2�/��j�P:��K6���qu=�`d���T�k
���H�N�����>V��7����u
���h�i���X�g����Mlg6��bfC�@^�9��2����J�Z������a�J
K��Zu��	���2����#[��:.����^�X��+�K�c��4��)D�cy��c�`��J���8�+0v���a� ��`�<DPm��l"����Xi="�qG???n�3�h.�JI��mb:����]&�K����tb]�H�X!�J��{�v��Gks�%�v��EqG�%Fts�etw�B�R�T(��	�������M�y�����=y�� d��p��=>��O��/y��E7|��W���y;��.� /����-�1YL����I��h'�$��=��L?�w���a�TFD���[W7�?{k����m��^��^*�vo}��#I����<;�P�&���8���_����d�����[H���2��W��O"�����%I�mw�K2��0JW�AdJBi�,�v�X.(�Y>����Nl��v���h
�����R��2��	�����x�W7���)?qq|Q�I����x��)s���2�d~�b��Z�lu�����d�~�����1b���QaE�J�Z�������s{��������?��kT�0�	-����B�>K�*^Q��[Z����?!)��i��y)�L������������J�q��(�X�.U��"|����IG����[�%�W^'������AEn4Y0�/�����	Kz+>\�6�����z��n�Xv������c�j ����q�[�u����@	C[�sIuh��Y����}����������O�������R.Q?{���V
����X���K,�0.A�����U�o`J��V��	y�X�k�r~%V��V�@&���9�A�4&�Kd�(d��r������ 
��8h�r� �*��A��H�m/������C�%uM�|���]h}�I��l����p����Ao18�,�ml� 2]�F]2_W��|���	k�&�Q���(��	Q��^���K�K����tH������=���2 ��������l�f#���6q�h�mo,�k6���js{I�O���%)�2;c��e���4v�X��f;��K���b1�k������n!�j������?T70�<����Z��'t�����j�[����)7V$�\X~�{_�v������*:����2��07I$���"��MD�������(#���)(�M�����9RZ�����Y=��!i�d�Wr�tr�8����@]t�M���("9Z����8R���I����Y��P�l��gX��p���f�����e���t��{P�j��C��T}��K������VY�<�i�,�sRC�.��'�z����Y��|f��u@�5�		h��|KZ�>�e��^�M{�����AxLQ�;@�����P|��`,���E�R��k�X,B��)�Y������+���`�;����Aw8�0�����_��],������?��d����8�����@01a{��kC�9	���m�<�R�2�����q����
��	��V����B�v*�d>�m�|P(��6~�k;y������-�;��Q������"��7�d�j�,l"��(����IQQd���|����,��.�
�t$<�������b�?)=0��A��|�a��:s��RZFQZ����f�1��d��Z�/H�B^��Eq�:�����f���T�A���d������ax�Ywl�.y������\�Ya��H�tG�v�h�5��&}�E�����~0T�N&�)9��Uivm��5z����O�s*��J��d�����2��u�O��l1Z�r�2��d�����>���5>&�(I�YH��$]^ ��&R���f��kamat�
�K)�P���}��~���M�Zm�VA��?>�/M����w��h���\����c��RT��"S�i�?{����>�.�EZ�����
���d�L�^o5�O�[���4�J^�Wa��6���O�kSO���W�h������1�u���M�W
�	���(��/�m������z��� I����o1��}������c)�h��2*|y����o0g���/�����	��~��5��gul=����'����W��n�)�HD�����"t����'� �;k�p�� �^|4�b
��������5R����|�M�l=���Xv���P���9����?����/?�g����������h)�����S_�����?�)\�W��`�����N�����y�8�	 }����K�9�q�l�Z��I����m�]|_�/��>��V��q�h5�-��}�������������F��Z�����o`���>����A�����a��L'@,M�/��i�8{RBfG�A���[�S�<�]��~2H0�Vw.O�g^;���Y>|����lbah�
P��yD����H�]�%��-Pb�?�V��B��?�����`�w���3�Y�j�=��V���x�j�8o[����fN����7X���l�/��p������z����"(��\5t�7�k����lG��C�5	��Y����%�v�U��=�W6�W�k�OZ�v[P,2���j<�o�3<����2����3�h��w)JuL&������W$'eY-?;��^M%�+T�*��n�DBQ�I
o��k��`@��@qL�|^������������?�Wu���yY����{a�6K��|��MOH}�����yI��7P�@��R����*{0�x��r��*��U�Se�G�V"{�D""�m����W+��bQ�|���:;�X>��.�m��'��>N�r��d� � ��-�A�'��-������5H����N��c����K�G8'�i�M��=(
@�����RVJ*�vK��_���� �U1����t�����D��,���#<?'�K`��8S�V7��
���OG�8D���#�p���3>;p�N���@��pPc<�����7"���jQ
�K�Ry��
�K��^�,FH������R�Q��T�)Qi�,�r��l���X�������"Y<"��o��TC:*9QzTJE����Zq
��[>�u���kV�z������g��>#�]!
T�S �\P$&B� LDd��W���e�X��.�>���X��,�v��o��gR%�����d�;76�@3T8�T9�X��	����IN��'R��5j;����A3eSj��%v���c�:���.:���t��y��a�2���Gu���M�DU�����<���fe��>�[�g/N�[K��7*�����)%�����E������N����=(	.>�����C��8!�gc�G4�$��)��r�qb�H1}O_�)����!��vw*�IY���0S�{���c��`�B��4�|`x��6���	W�n�z�^����=g�6j���	��*T@
���Q2�<"wa�m��,�����<wyT�����t�m�&6�r=�0��{;�/UT6j�
���\�O"����_���u�;B��@
V�)[��/�T2*�XY��U�?�������}^?Q:�q/DGD���.��P��UP{ �^��##�����}�"�������MBF�RQ�6��Y��(i!�������������0�,S.��e�����]:���|��+��p[/�2�
�y)X�y+��)��O-=aY��'�`�+��������I����()k8d7;���Ci���(�to`�~I������e�K}��.�G[VJaeF����������z�}�*�e}k���Mrx���X�1���3��z��J��<�X�s�|�����f�o(�M�N��U'E=Y�Q��]J��R�i����$��������Wc�����%�q���?��X~�I��+�qOA.}hzV�'K��>���G{����~uw���G'V���i������+�G�Hm��[���5t�?H�����VR���r��B����:��0^��U�(��cU���Z:�s������V��hC��I��/�Hv�d��u�hw��t�����3�������D���$���)��C:$7O�2wi�R(U���;�������mt������f��.���JL�z�
���L;2���j�J��r���6����WR�]RD�/d������-@�oL����~��/�A�-���[��[�W��AP��;00�9�&W����l�8�`��.J����p/]��q�-
:��%��- (.��]_2��+c�"������+h4[���'Jb��������b1���*��5��6��&�	Q�e�i�(e#�����"����E �"#��0�b�8CF��6s���A��_��#�o�3r�w���5r�[mR��X�
� ��z`����/lE�(��x�9���y��/������9+��.����E�E%�=L���s���4g9dq!���H���f���H��J�n�>������07����g5�fsB*���Hj�~�T���n���
f�7��; RX����1����IJ�)�������x�3y2��yo�r���k��n��
���r�S�����d����Io���z�9���7mJ��g=[*C2�A���F��hd��!�=����:[�����;;%����$��A���7@OI�J\��O�H��o�����f����;)syuB�Kb�a�PsNJ|ZGV�|'XB�������/�W��^L$�T0��_������N��m{0I��u"��b�W�v���!0���
�����G�U����;���[�2�P�C�ztV�w�?�kI�/��!u�����K����uE��'��w�����Z�tx��S�-��|q9K0�������'uzM�����7�KZ���\�-����b2z�����1'��0m2��aQ����x��/y6+A\�p�0~�Xl�9\3T8x���D�pr`Ct���G��m���������r�D46���Pn.*c]��
����1�5�M!�����#�*���;�N��+TP<��kW_��i����]cV�v�L-�umx}����7(���Ld�
�#���7��2��
������_c�j���&�����I�vJ��T�P�RK�$w�
H�������G���4������U������b����v�gdi�<���������(!ug�w�0�Umq�m�z"0�����Q�}����m�OPD"�w�%�S�q��C�<a�L����"�� �����oN��|1����\}=��*������|�@lc�R��|!v���P�(l�a����1+�����>
`����c�����
y��Lx��
�U ������Pp)�W��j_%����*�;[
N+�9�O��y���Y\��p����\]�\��0l���������xq\`5s���-����"����qZ��x��c�@zd����_�,=y��d��qO��������H����{�V{#��2
T�����n�y�!�$��yY�R��]���T���/���qwd�Y�W
�[��m���ow����@d@T������1'c������;�������u�X�s:t1�z�t2���&������t���7���rsKjSGE�K��#Ln�K�M�X���JoT� 6�/)o���I`�ISP���Q\3��C�<����,kQ}y;��Q�_�hn]�L�<���G�r�KoN�����%Us���p���
$@���0@��S!zGGm���u�S�D��&/���f;���<��A����R{�w���<�wxob8{}q�$rB��M"V�oE�	�*g\��h���c@���2�.a�uh�1	C _x���L������q[	�\a�:i
��c��|�tlU���wn�2�U@z@���s0�������M��M-�pQ�R�v3����.)����;�uW�x<^��u�ZC��-�K�^��VQc"�/��B�\�>>��I������=��SO���9eyF��f��&3V�v�J|Z��+u����Y�"H9qe����{�v���h"���U�,=���u��k��
GaQ�.���;�#��3N��w���{�i�
��%r����a3/jI�	U�-���yebS��7�tg�A� ?{3A16�&P#�s+�48�[�k�6�p���� <�d�;��)��xFl��[���S����@:o4����m��jo��	�A�)oGp$_���o����,)���������m4�[��
�E
��`F���=N~N����"^H,:�����0'��x6pn&��Zc~������������o,@o6����qRN�7��V���z�d$���-��U���|N�E�2Y��+Z��o=?��G�1@���������~�|~�8s�z`����*V�Ki�c��=����M'B��4"8-�s.t�'��.����T7"�,,c���l��,V�E�C'���Pq�@�;3��������Y;_�4��.A�Z���u��t���I>oXTI��.�E�L	W��{"I������I��X}� �7�����a�we0cxI;��/k��rH7���l������j���u�������h�y�m~1���z�9n���5���'A�y�a��v���-,���a��D�����~�y���)�+b)��E����o��"�%�����~���������Z!v����e�VQ/r*!�:5y�:�p����O������i^��T���������~�����E��x�6������[Q��K��?�/��r/P��
���BY~�v?��v	N�39�u���
���v��S�w�s!X��F�l�����#������`��c��ooL���]#{�o�a�E�hG��xs#/����LMa�xz|zz�m�����
;4r��q��	$�+�}M��Fm'H_m��H��i�Cv���#�+Aoc��;
���2���b����=}����Y�'���
�Z���8k�\��i��9����y�q�<ou�k�=�<m5�w0t>�k�^�[�n�dV��]D��M��A����0���U��0��rB�������������z0����O_� (svVA�Gn��]�hnfA�sYW4���h�$Qlg�*��@,D���/��){������yl�gd�'yH�1��
p�'����;BE��R��)x���d��L��\6����,�J�z	��@��x�������=/���N�|b8��({�*���w��X�%V�<? ���_
���o��p�>�M�x*�O�%R ����=���	S|�������*������W�������C��;[��m����
����Cv�O>N&���s.���l?��S�u%��F���qt[cbG��eqy7b�u����e����X���1�����7��4DL�b�����U������WDbxl�8�F���2���i����2z{���nE�C�a[�t�vF���W�Y9�C�QM
<�>�w��L&��>�@ef��)�<��K/Ol�&�Y���UD�1����j7K���b�Ie)������h�
[�de���s�B!�����t�8�Gc)��X:p�[E-2B!Lf����37���	"�P���b@*�J��R�\����@� *�����)��<:K&�s`��3��U^\��#�������lmW����c��*fS�C��!�>O����&`�++��P�����0���6�`��)T$'NZ���~�CC�
,
q�-�|&IRK���Sn����x�%o����IrE����1z���&���[��lz3���b36�#�#�t|��93'"���Z��F�
��d��H�/��T��#��#YE#��l��t%��p�eN1O�x2��
\�>����OA��{��tZ����(G�]��2bO*{c�9d2:r?�,���X���V�gh�g��Q�PZ�R8���2� b���2�gF�p���Lc����0"$�����11M���������o��S�!���k��:7m9�*�J�y�]����4��<�E�l������	�����f�����dD�Q�w���X��Q�%�i��!��P�I#��GA'���>��#��FCn������;uv��l:����!dN$�4Z�Y`�;5���{������l��;t���Z
b�%����9r�������,0q��KP3��jA���aM��LU��{���)%mR�����`�X������F�V;K�V��d�}��A6��|�.�[��2���qG6�Vq��m.5�������w,�(JEBvo�7���CY����sZ��[����{����P�t}oW+<u���n���h����|�������.�E6��2{zI�6,����!���.t+KpG����'1�|;?]����D���\v�h��=�8��@P	p��e��|�m*�r�+OIiv�~+�TJdh�E �b���b���`�H�6���~�d�����K�]������p?}��[
�.�,y�(��m������b�S�H�~��Y��y�R�6BVm�_����:���M�S/�5�����jk������rB� s ��8v�����a���~�	e�� %��&L~�UrE_��.F��,�W��\�=���Ky�����j�j 4�"-m�4�
6���0!S�!^�|$A��oP��3�bdA&��
��;a�Qz5T�����#�k��������|�Q�0�<d�>O���wJ�p%��DYl)e/�6������ �`��@�Y����C�	�)|�H�Hd����fl%��E���A6�LO������!
E
�"��=�j \��~������)g;cl���%�7bk������#rQ��GR�����JQ��)���,F�w������t�A��I�����E������F�tP��������
y���>�H5�zx�����`u���Z3��c�GqG~�Bi���CGkxn������p��$�� �'��	X</o&�����h�0��Q�{=�nSc��y2�'�!�#�E����y����F�]�.�l�K#���� ���#u���Y��E��;������:gp
-g��(aT,~�����V��!��H7Z���K�8�5��I������������cs���q����c���7ckxa%V�������j���q*At���w����:�f|���{���R:���-X��!��j�Z��P��u�����8x�yst��TZq�����^6�F�������!��a�%���<�X��NkLF�������h�6G�G!v�������Jm��osi�
3�����*�o�ps
�����{QQ�"��O
�8,�1y�+��%��g������I8�����W�)|Z����YF� ��R��2��i���t����6i^;��e����BwAe�P�'�0�"=��������QV.p���R���M��Ii����e��"���w����g��FP�V����%@�n.�g�7��h��B�HnQ�	)}�#6
�z��C%���gj��ly�{�������`�=�~�,�d�vd��ctA��yW�4��������i�e��|1��x��tQAk�����1��7���JDN�����u�W��#�3���5Q-��K���1>�U�F1�.�T
���1]�����l}}����y'�:t��J}��:���2Z���F�&G��I)�+a�����C-�#�
���A!������!�����q��&�Ep���D0$���~;Y�y�nO�����QSp��6O�um��i7����z���jb��7�JvoM��*\ �@u�s�������t�i�mP�dn�y�BN872c#�#1�c'u�����V�P�����"��W���+���o,#/�ETD�>�.����Y�u�[��nns�s��������h-4@���VV�i�)�Ey�InQX��d�M3����2r�S��0���;[Z����z�����t�B�BK `�&m���4�/���\|���a'��Q������2g����5c�A4�rb����1>QD.u���J��\���d>�K��&��Gu�Iw�4��=�����R"<:�������S�^HWen/��
��g>��u=C!i���`���f�^����������_��0L+����-�w�wT��e=y:D�2I'L�����9��b�	���r��@�(�M<�{S�u�,�~A�rp-��1&b�.����3�DCZMq'R!�h�
5 ,-�x]����^��wg#z��i}��iP�C��>��a.�����wH��P�@�[?�Z
��d��Z8Q�r�;I�#!���;%�g��x��;�VI�T9I�H���e���e��
�Cy���'B!/v���|��r(i>�,���C���d��Cu�>�z��
�Z������M�J�N�@�������a��� ����`l�����$Y-�����3~��:h#h�p��/�����*������m�1��b����'��FJ�/U�{��h2��1�����!��j�7�I���\MF�0S�
�/yZ�*�7:����D���c�7�����l��!�������	�8X
���q�G��L6�4�B^�S9>)�#��P�[�����%vf�r�nl<|=W�wO:������S�m�XPe/�,��f�����S&���k�B��/�ay6���U����9)E���b]3@��F��jL�x����&���s}��,���^_'���ZFi�a�Jb8��~\����<���	�O %���*����F	X`��H]l�`�����=�
��T����"Q��&]�h�s�F6c�n��I����D�l�<M����Q���z]��K����@T�%t��F�2�PG�9l��v4O<A�ep����:�o�i�|5|��J�{�@��2G�������o1�����]!��L[��!�X�^�B���:�)t3����=c�;B�H&�13���	O�-:���q���t<�G��t*c|���
����������i-�����I/Y}A�|��ZE��b��N�v&�����8�M�.,��|o��[9�!	���f����M�?���|�2g��0s�~������
x�8��{�t�P���J�Hrs#��e@D��f������1)g�\�U%Kt�~eS��3Gw
K#�i�*���I[u����V�R�K�]��
[��&H��cd�8#�*�����I=t��S����g���+�`�N���N�b��]�(��W N�k%����&�;�%��l����7%L6���-�$�\��W��d�d��->�66�s%G
���hW7���3�pb����T\�I
���y��n:�w4��e��%D���P>@o�!�i�T�X�� ���+�m�6��B_37W[���},�G6���2W��d��������Sp:\$i�(�m��~�!3Zl���^0���me-���2�1^��?������cY��X����������KC�����Dr�����rG��]���n�T����cRd�l��D��x�{���W=~;2����N\�~�g�����i��Y@)�AA�P&�"��:�DA�����ihG�W���wq�<���	�v6}g�WR	j���=��������t��h�D�'��y
�rH_g������ApG)�����)_ys1/D�
���$>�|�������������x�X`v3NX�<���*#M�{�R��_,�j���n��R��,����: �/�8�4���`d�1�AA�3x^�OR�tt���U�x����������dB�������X*
������?O�*�Y�������TTg������Yb���[����F�m@;d�<��`�
��O �'?�i�D5�N�yi`p�["�2���j����S����/��L��9��i�|
�e��;�k�'�@�����`�;["9��]�ag�a��-=8���Y�gWT)N�k�4� �����M��l�E�{��u���ai��V�{�A�V�[�������s�8`��&}���`�^z�Bch7P���C��e-��������d(�[�-Jh+�(������D~���7�S�����7i�
+���i�C������%���*1��mu�9V�!�8c���u�������)�4�#�Tc�k���"�Q��c#��!ra:�����
����d,����B9�wnf��g������������^�\�(d���c=���G���������y����>��(�NqcT�w���S��Ck�Bv5�Dxw-,�;��(WW�8��N������'����\���}/6�8Z��YF��H=�Rh��z9�l���8�("��0����X���bp������������&;��`���]�����$J�f�����i��;�R���f�Mv��u[joMR������{-50VP
s��JAJ9H�)ULa�/��
�6.+�j?']��"�>�����D.Q���:����i�Qv��y���Y[�\t�G�y�~q�S�q�Q1U-�~�U@nk�8%�C�_	��5����p�������A��gdN)�����@�j�����f�A#v��)R�����N����R	�����q�G�k��V�o�*���de��9����Hev�����V��J�0�����P�z1�(�?����
��Y'�qQ��Z�|�h��Ql;|N)*;��t��Z���	Z"���g�{�%��{0��s�D>�;��v���gu��5�=�6[�'�M��	���t��������J����9�p4V��	���.W5����_�V�Fz!Pa��pO�"����ey��F� N���;�=��E����O��,�9S�~��DV��2
�_ZMJ���!���y���e��s8�������h5��)g� ��)�����+n��! U;
���V�M�[�7$��S�)��K�J;l����UWr��_��e�\c*I�ADt��gI�R��
GL!����������4�6��`�6g2�v���kls��w'��]r���P)����=r2d�#�T/i�AZ��������XDH�P:e��{�����$�Z:[s�{��5�=�y�N��F�>���o��5��)-'��A������B����u\s!��M����&�hYW��G��r.(3�u�/���V�/�-d��##U�q�(7#�	H�\`r����MH��2�^���,��`�Y�4kke����2*����~����:����.�����L/���I���������uA*
�,9���
�Y^��j�6�8]P��b��aF����q���(�J
��:��qZ��,x�^�E���G���a�wX�����~yo�>g�a���J�c�<��G��Z���D>��f���Bj5O����ne-�KJa�_:�c&UQ�+<�~�g����S�M���u�����oz�Y�K;#|��;��t8�=���Sz#�|�{&�w#�n<v)����y5�S|�>;�������V[>����>��Dm�g���u~��v//�6�J;Of;q���!��E�1]\_[o����UuvF4 �G����<����jr��-��Rw?��#�[;Dm7����_�8���%(�����{	���CQ���B�b#=�)��S�n�m�N�]����}/����5&��u ��g�}��8k>��E�����Ui2�]��9�3��6���M�9�7P+���S�fN�	��a��>�]J����T�Y�Atoe��]@����p�O�����,�%��4�r
���]��>K�Z�4�I���7G�u$].9�_T������x@
�aJ�$��aw,���0x�*����,5+�*�K%��P�sV�{$_l�����!��D�:��UD���	���s~1g��U����j)����iU�;�
�7;�Q|p�=��~�\n=��0���J�:�Z�(5��3�������g*u!CbAN��)K-�
��(���F�Y�����u����!s�j\*!f1�C5u�FS��!��U�>-������^���	��N�1����$���1V����o��&���E,���?���k�
h�H��z�)u����Cf�n~{�����b�K2�z��N	�B�a�`+�m����H��3�\�b��C64�R����w��od<����%�k�����;
�j���J\��/vn.cy�(�2�H2��`����jo�(��������r����F�y��Z�)y��m�n����#�{��C���O.ry��q���g���;{6����M������^��X�u���a{��za[e��4�W��q����7���L����j����H�B>&j@3�x~�N�����mo�n�#�Oi�
{��A�(�'4���3�P��~$�y�PupP���6��2t��>�x����Z����F��3@�9'�DE�/Z
;�UX�����q�fl�@uu�R)-����m2$	��2*��x$�p3�!�����j����%0����0��N���"�a�����
�5����->�@g���f���^��*�,������������1�,�x�o�U�e���#C���8c����n�#i��C�)�Gr�N���������K�ry�B�����S���k�K�u���-"�S�$��9��N1J�b;��]Lj��n�����
��>X�:���������*it=��wY�����{���Q�U)<�h���:���B1� �����QJ��E����Q�hu	v�������h����aUZ"q*��^n�F���F�h[���|��a������b��R��b�Jk�\Zp�����e���C�UyX��B�����]��.�^	�r�]�jK`��xX;[-#����"��t��+�����Z��$���w��T�_?���$���@?�,9����������a��{y�Y����8i�v����U�����U��S?�?���&��S�H��u�`VS5�>9F����$3v(��������/kk;h�(@�S�k����M��f�6����������U��|_�R�wT����]�]��Bt!Z�1���������c������of��������NWn�A�����Q�A��*K���{�����v=�%�X����������2�+�������y�����E��P�>�W�-����=Q�Mq����,���Z�v[X�L�/�]��q�/�~z|Bc_��d�u���r��������y�8Ya�/���s7�m�n7���D���a��Z���[+/���VRo:��r�T��m�w�zi���
w1mOgL�Fb�B2��jT;
��x9�&�q��sA��ob���c�5���FX-���=�Vm�e���W���eP�]C�U�O���6��Va��H��PE�c�8`[��������-���I~d1oY�l�?��n������T���'h D�����	a�1'���|�[7����r�ON��x�������Y,��R���T���	��{���I=OD\�27hB��}n��]7H�G"�1{C���9<��q)� �[z���I���P�/�[����rh��f��Z�g�Z�H�2_+Ez�0{��x~s�����*@$|����O���d����?y5�Xb'�t����U7X�0�lX(�b�G�6���������m�Za�1���������nmn��3�r�
�I+ �$��������rAZ*���9Y�C�X�2�\>]�w���Y�0��+m���qV���������m��-��m=�wK�mRh���t*��pgNJ`�����9�j�"zX��� go-��E�sX���>���J/Y={k�g/D����(~��j��'�:j�����(���:\��f���9�^��/K���>/v��D���E�2��\���4R��8H�c ���`������\%��o�}����Ge�����R4��*�W�[�c9����B+=i5���=�~�����Q�h,G&5
���
�#�I�u1�7���[/_m�����|D��]z�$p�o�6�
��V�6�0�*Yc~���m��J����^����:u�tp|���+�_�����cZ��	k>/z���-0{ =��.y�����v@M#Vx�PL��`7�py��dD�+�yow��� �
y�*���x�<��������|�`[n�'����3��O[a0���V!������w"����|-�` �hj��q�0�I������*m�"!�����
��T,W
b��z�]����|�^%+���~A���6��?@9h��
+�kh�mnBG�xI�9����^����zK���8�@�W�R�m+��Q�,,��4�����|�
��&-�kbY��e?]��0O���\��'t@6�6G�,��N�`O�V^��j~S�/~>R��Lz9��6�o
���g����[����|/������Y������2��A�x��j<v�����D�y�B��E����
���X��
�XSf��"���.X���	2�C����4�HJ+Uf�!�P%,��h�/��;k�p��o��U^��������FC�y�����C�H�1S�W�X����+��E�F���u�I+3��x��� a���/�����8'��2��������������������|������~�?q������������o	>
�oe����Uue�IXb��k)'�],�\u������,���2���4��s��WM<���ri
]�V�DKl�-�,���H)��O�#�����
06�����<�����e}��/����g:q�����������+���h��������������3��~��e��W�a����x�$�}X8�1H��N�O�2uR6�N�p�73 J�+�|�7/{;�m��������Oaf�+�e�����[F����O��d����
�^�/��+;!��@������lX~�@�-�"a����ae:�����K��UZ��5������%�[a��z_�����y'�M�����W�Cx�:�s���"G�k�t?R��
�^/��}�}|�S'���3\�fM0>'���H��~�����6^��Wa�O
����EZ�b@Q��7�a!��O�#��� ����8��	 |H������X����^V>*������|3�������*��$.:�v5�����aSH��2��t?�LL,�vg��t^�����>>�	J�k��M�-�V!��X���ag�6�a����TS������{����:��S�mw6 ���R��}����R����Q�V��'��UJ>,��m�oR���$���?n�n�e�[��[������^���^������h��������s�������Q������>�����W�aX��h�S�	�Y��h����Uz+�z[�b�����tG��[�?6��
gU�����|��0#�b��U�)��Mq4(����Z�%�����0�
�p�e�v�VR�Z,��XES{������O~ONi��k,vjJr)�.����
�#>�h
:�2�E�������N::�^4�q4���\�T_;�}�fb�R�b��$.��q��3%��-[��]�:��1�$,�(a!M�$���>j��t��dI��C�t���'T�t�?Iw��r
���K&9����6A��6#��Bz���.�V����C��z}]��J��-����J���G����K��"�G-�W�E�DU��L
K���B��W�)���������kZ�X��5�o�W����rQ�-�?N���B�.,�q�_�JQl�?I������!a/�d�<J�_H�Li/&���|�������3��$�=��:w������#���3�;i�a�|�� ����i��yO����o�����_��L@����_��M����������o�?�����Si�%�hK������&��{)C�dL4�J�	$#��41dT�c(r����1�1F���d1"T������1 �d�1�a 1����0��P0���@�N���c��4&�����H�zZ�gx�P~��I�b�����Q[�dmAZ(7����H�V��)�����J��X����S��F�E��5�-ZZ.IJ��Dq�PD
d6K�x'E�!��E�0�|P�y��n3.���jE��<j�U����G�"�df���o��X{ux�L7`l���l�#��W#�������C-IB6{��e���cYg�%�N=�v	��l@s�!��i`}�IH*`JkI�\R�M�Y8����r?�q���y����Y���R]le
���F��I�Alr�����Q���,�l�4C���Z�~?�������a��Q?F_����Tr:t�������LE������D�
��I7Y���������aGB%�]�r�����-�������hJYn-l�@����x����;!1C����S:R�	[}'a�V>S}�f~�9�a������c5�IY�w{H����=������p<��"�*��%����pP����@�\%��a�;��{��H<������w5�?��w70��8�{��wIH���B��3�����
Y�������ED�/��e�(���r�����j}���
��(a����2�A�[ty���>���6�.O|�p���)q
������9��i�==E�#��K����V����?���E3^
Z�^	�D-��?\��J���-�E���@.JO}�8�~�����W��v�u!`�����m�P�^"(~�D�Q*���o/_�L��|(X����DE�+�*����[���	�
~mVQ�Bc($P
$�����	eC@�Mo��(X�y2&nj���<4BZ��
��B#f��d�k�A�5S���&�����O�>�hb_��)�K�tl�A��Yl1+=��D�j��|V��W�����:!!1!���������>r�w� F;����+��B)H))� ��:�~JX��e�z��K����:~�d��)�L�Tr��m7��I�+EW�o�S�o�P�,:�y�Mm_����5��C�&�"����y�[!��;O��n=��h`V����-T5�F���W����Q�����?	c���o��� �����}������~�������������\�;w%��N�����{�o��GNSJ���!�WJ�*�gU$Z�4��UN�r�t@�����k�Y���Y5��)�O�*�gU��p�)Y���Y��ezA�
�Y�����$��q#��%�VJ�S+����Z��,5���dU���*��0%�����0����jzVF�j�+���,+�(��jz�aJ_���R���YN_q�F���Y
xs�r�.5�����es�J�8~���|�u�en���+��]��q�����u%iN�f������r�72�����_�m�L���c�����p���kpP��id�s�$��{�U��.��&�_�}}=�]��?V@�5�a��n7H�+w��gD��7�<R,�J�v����5M����4���1�]��Kh��/�w6�zhCd��<*rA�C��)i����R��E�I���s�x0��apA���/�F}t���t�d��Ve���>��qtPrnzG��>��D�_�#�
�����%t���;�����	�j�~��_�^�y�XF���g�����5���v�//FG�R�:����>���(FQ���� ���o�r���k�/^�����*G�<=uv1��,�5�������Yr	���v������SUG��iC��yA~�V��M9Bz����Y�PA`��[q%o��i��6�N"+����8����/�l.����$<e+k�s>�-�O��=�*J�n�R�]��`Xv���c7`|�������1�aew����a�[��.�m)%fL�,<�P1��+$qR�)�-�2�%[=4�������F0��������"��������{{��`�����Y�^�D�R
	?��w
����-O,>��r,�?(��~�p@����F����o>Q,�����������70�����f��?�y������g��s����u������'�O:c�p�rQ���0�I�]����F��o%���-�t�����j��Y }ZC�Oh%�X�QF?�m�a�s��:�m�r��#����,��\ae�����?�����R%�����[��RE�WU��t��D:���J}�BQ��w��Nw
��Rz��Zl����Kc���������5}�B5��t<t}�*��#d�Z��#|�XZD�n����~�V,���n�0��������U�5J��JaOl�g�����	��p����V2���I�%��D�k�c���������q��R�y����	�GA��I�09�S�1M����i0L���t`'��_�=��a�T�y1�%�>�'�B ��x"��
��,�=�6/��w�r����+WwY)�:Bu��P��Ib�����r�:��E?��T~=����^�Lhw���*	��A��_�>x���7��
0003-JSON_TABLE-PLAN-DEFAULT-clause-v44.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v44.patch.gzDownload
0004-JSON_TABLE-PLAN-clause-v44.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v44.patch.gzDownload
#40Zhihong Yu
zyu@yugabyte.com
In reply to: Nikita Glukhov (#39)
Re: SQL/JSON: JSON_TABLE

For new files introduced in the patches:

+ * Portions Copyright (c) 1996-2019, PostgreSQL Global Development Group

2021 is a few days ahead. It would be good to update the year range.

For transformJsonTableColumn:

+   jfexpr->op =
+       jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+       jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;

Should IS_JSON_EXISTS be mentioned in the comment preceding the method ?

For JsonTableDestroyOpaque():

+ state->opaque = NULL;

Should the memory pointed to by opaque be freed ?

+   l2 = list_head(tf->coltypes);
+   l3 = list_head(tf->coltypmods);
+   l4 = list_head(tf->colvalexprs);

Maybe the ListCell pointer variables can be named corresponding to the
lists they iterate so that the code is easier to understand.

+typedef enum JsonTablePlanJoinType
+{
+   JSTP_INNER = 0x01,
+   JSTP_OUTER = 0x02,
+   JSTP_CROSS = 0x04,

Since plan type enum starts with JSTP_, I think the plan join type should
start with JSTPJ_ or JSTJ_. Otherwise the following would be a bit hard to
read:

+   else if (plan->plan_type == JSTP_JOINED)
+   {
+       if (plan->join_type == JSTP_INNER ||
+           plan->join_type == JSTP_OUTER)

since different fields are checked in the two if statements but the
prefixes don't convey that.

+ Even though the path names are not incuded into the <literal>PLAN
DEFAULT</literal>

Typo: incuded -> included

+ int nchilds = 0;

nchilds -> nchildren

+#if 0 /* XXX it' unclear from the standard whether root path name is
mandatory or not */
+   if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)

Do you plan to drop the if block ?

Cheers

On Fri, Dec 25, 2020 at 12:32 PM Nikita Glukhov <n.gluhov@postgrespro.ru>
wrote:

Show quoted text

On 03.08.2020 10:55, Michael Paquier wrote:

On Sun, Jul 05, 2020 at 12:15:58PM -0500, Justin Pryzby wrote:

It looks like this needs to be additionally rebased - I will set cfbot to
"Waiting".

... Something that has not happened in four weeks, so this is marked
as returned with feedback. Please feel free to resubmit once a rebase
is done.
--
Michael

Atatched 44th version of the pacthes rebased onto current master
(#0001 corresponds to v51 of SQL/JSON patches).

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#41Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Zhihong Yu (#40)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

Thank you for review.

Attached 45th version of the patches. "SQL/JSON functions" patch corresponds to
v52 patch set posted in the separate thread.

On 27.12.2020 01:16, Zhihong Yu wrote:

For new files introduced in the patches:

+ * Portions Copyright (c) 1996-2019, PostgreSQL Global Development Group

2021 is a few days ahead. It would be good to update the year range.

Fixed.

For transformJsonTableColumn:

+   jfexpr->op =
+       jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+       jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;

Should IS_JSON_EXISTS be mentioned in the comment preceding the method ?

Added mention of EXISTS PATH column to the comment.

For JsonTableDestroyOpaque():

+   state->opaque = NULL;

Should the memory pointed to by opaque be freed ?

I think it's not necessary, because FunctionScan, caller of
JsonTableDestroyOpaque(), will free it and also all opaque's fields using
MemoryContextReset().

+   l2 = list_head(tf->coltypes);
+   l3 = list_head(tf->coltypmods);
+   l4 = list_head(tf->colvalexprs);

Maybe the ListCell pointer variables can be named corresponding to the
lists they iterate so that the code is easier to understand.

Variable were renamed, also foreach() loop was refactored using forfour() macro.

+typedef enum JsonTablePlanJoinType
+{
+   JSTP_INNER = 0x01,
+   JSTP_OUTER = 0x02,
+   JSTP_CROSS = 0x04,

Since plan type enum starts with JSTP_, I think the plan join type
should start with JSTPJ_ or JSTJ_. Otherwise the following would be a
bit hard to read:

+   else if (plan->plan_type == JSTP_JOINED)
+   {
+       if (plan->join_type == JSTP_INNER ||
+           plan->join_type == JSTP_OUTER)

since different fields are checked in the two if statements but the
prefixes don't convey that.

Enumeration members were renames using prefix JSTPJ_.

+      Even though the path names are not incuded into the
<literal>PLAN DEFAULT</literal>

Typo: incuded -> included

Fixed.

+   int         nchilds = 0;

nchilds -> nchildren

Fixed.

+#if 0 /* XXX it' unclear from the standard whether root path name is 
mandatory or not */
+   if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)

Do you plan to drop the if block ?

If it becomes clear, I will drop it.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQL-JSON-functions-v45.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v45.patch.gzDownload
�1�`0001-SQL-JSON-functions-v45.patch�=is�6���_��t�v�[��O��I�7Wm��N�GC����"I�����]�$H����}��VA�b�� ���fl0�Z{�C~��M&�����^������d��=��n�=�\v���{�:�c���:�n�!�9f��k;4�#'��������:��y�������Z~tR{`���]^E
���'�X�Ggp��l���tj��
7�c��������n{����i�����l�fh{nP���f3�,�e:F���6@���������F�s�[�	����F�_(�������7�.�����}�uF�Rk6�5*��q{>���q74M-�}b�����<����t�������7+� d���V�!$������]��{���6�����7;�&������
?���GJjl������7#�8�8�0�a��9�GHIs	�c7��<����4���a�q���.F�H�}����,��de��� �>��+����pJ��w$�u�3��W�� ��VR�]�Ea��4��[2��
������7���7��s#��a�y!�n5�@��s�A���>(o{���B7Oy��hVS�������9��MdJ������A�`��B�����
I��[��
Cv������mXa|��z@�E-�mw�c�`� �]l�b���VVY�q�v��z'������`	�z� ��,E�(R�d�t�h���{�������JG��/\�zff{����KV	d(�>�Z�1�;\B�ni��Y�
���xS\Y�)�M�-#,�W	A����'Y\����G��������E8�������J84�C��(G5��H�������+�Ju������f�L�).FO������a��$��/�W�w�/���i�!�9h�%���	���0121���>G��n������ ��z�Mx�	Gk�s���ET�����o(�{�!�)H:f��I"�
�����v�������xs�.T"�[������/��%$�
���(0���?�LG��6���{������u�r�Q5��R?(.\2�/Vd��JP��f:���5���vx��+��r�r�����i�����`�N�Y�����[C�C�f�A�:�������3������z���@U��eO&����!3��n���B�l���A��v&��ago�Kr1�>5��
(��g��4@����=mO�����l��A ./��yC�9r�.���?�G��l�N;���4O��9��%.�;w	���� �����~0������CZ��������C�����������*p������g��E��	n>v������Y�7��������B�y�v�O~J"�{9:�x��i�B�+=`~�������f8T�ar����h<9�y��!���o��}mL�r�qk#��������L��gw�W����5�@@&�v�LJ�6=���^��(DAU�}���[�k���nc���s7r��l~����+��������X�����j�"z�X��)X1������;4����
^h���>w������d�7B��y�4��iF�?�X�������6,)s�W�n�\c���Q�)�rtqy����m`@�,�&��`�h�����Y.�����D,��%lqG0D�(�+��y2V���7)��'F�����	�|M'3L�(@3JF�X�]Oa�=��6+�m���X�?fc��������n{�����������5��M)�cJoc�r�w���
���x�Z���������/F��`+[��_�������_�_����"�k���#|Y��U������
<:��-����h���v����O�id6a�&��u����s��z\���HX6�-��Q����h,ja�C�	K���M?w`����	����������2���`qK��& D��fnHg���%#�Fmg/S��4���1�!����3��HG�&�b�ke����-��:{b��W^��=�u��K�S�>����T�cv���[
.Hr���I�O�	���6��UJ~��.��5���^��
�5f"���Of�<�\��i��
V�}/�Z�m��r��s�`"��-g:�a;#U�w�����xM�%[����'��E�����E�q�
����h�����]��������D���?��k?�G�z�����������0|���_[�?�wj�����E2}���~��J��M�Nilv�IR�~�T��\p1!�5��zPb��o��*r��%�"���H��Z�0����q�N4v�k���� ������}�8����C����,�B�p0n;��]^q�F���}�E+%�Y�X��Ml?����4*f'�a;�M�y6L��q��=G����BW�f��,���,��s,";0
����#�q^�t�������v�]�m�qH/��D�����0p}���m���}c!���Y��O7#�d<��ql�E������$�#��:�DpNx+�J�n`�r��<���|����p���#�j��;�a)t�.Pg�!Y��c��p��s����/F��kzN4C��<��r����m��
2��Nqu97WM�#��C%���:)�	����3������l������p,���42�\��e���g���0v�8��=lb@;I�Z�w��cS���rP��{����:��&s��(��t����L3r!6�$d@�����Nl���2X�#~6�p-��15l���P�E8P^b�<K�@H47 ���``n��a������j�b������bUy7"�����k����n����j��FC�q-�BN�(��4�����mw�
T�@D�&��2v�W�R��H���a��c%a�bPi�8n�B"7���d�Tp��h;l���(0���$��X��+Uw�_!��<B[s��.��>==�.	%���������� c:��t���w!��#O�������
���My�[����<�bS��,��4<_;Q0�7����K��8a����K���heC<o��	{������pvJ����/<~����|xI�(�i���G����_�'����Kv�^=���3�����q�"����W����!�_�09F�x8~�'���F�*PFw�Vz�����
'�=N���c�����m��q-G�+Y�`mbC��M�b&{�W16�L`�W�����$W��e�����:d����e7�Ia�M1�4���T-�"��v�.M*J��b��*��2�H��!�B�S��s�w���re���+c����o��C����-�1��"�F�z�XG�..�fH{HhK)#�db�%�Jw���e(n��r�-ga���Y�%B�J�O����$�)\�����2�Y��E����)+������u~#7������Ol��8�3+���X��Ml����:V���H�������y��g�����U�VMZ�BI��I�"d�Y�h��.x��R9���tY�3�Z�&�*�T�%-�����]/�E���~,v�d�b�+�����&F�2���m]�����z�B���hPn��2��cv��)~E>���DS�g��&��U��Wu_$��r���u�nH�La�W(3���m�^W�aa��gv���*3�*W��^Z�Z)Jz�AX����:u��"[�*c�F(�J27`zc	���#M)	�\#����.�A��������7g��~5{��D�")RO�u��)Bt���.�����@��>��Qg����7X}\?f2@��b�yu�WCv��
��n�����z�O���6���8�RW���2�{����)��`R	<����"�j����*s�9�#�(��a�P�$�$t�8������LY��|�ra@�e������b�l�'�J�����
����[�i���'��{���%kf��,�&8J��3��m����/��=������������	o����n:��
�M�l����b�.���]�,�z�G��B���1�!�e�<�������?��T��m��������w��s�L�\�g,p��3>��EH����&H1��L,���y�yYb6�GN�wSjn�3�UL�S�q��k���e3DU��+��������R��w����>����mb:i1������Xi��66��2��M
����_X-Z�k�6D����JL�?���WO������rdu�V_�������i�h�<�����.�,�U9���Fg<b>�T+8J(��$����v�"�Ol�x�9��]���[`7)D��Z�U�T�_=}
����8{��[�������x������E%��H&����J�K<�Q��|�
A~3 ��f��F7�B,�Y��M0�&����S��.���C��+Y0���CT���D�'�W���b��c��E�TU�F��zVL*�a�4�2g�a��H�|�V@�H��:
Q���J����w����s<6���&E�$�+<kO�L:���������Wi#6=P.���
=FM��cq�����9Y�^a}v��l���&U<s����i�E�8���,����E!����*_��O=�.���{��	f1��������	m|m
�k�����}���������xf{f�;��P���j+�R�.	g���EV���e��<�#��L��VqW��Z���d���fI_�[b^I�zu��b%��_Z�^�	BO���.d�9I������j���$=����qy`�hW��5��{�n}�������V����S'�.@�v��%�l���*�K6���&��h�3&����5Y�gk�6���M��W�7�)4�>���r|`�f��$�CX"?O+�p������?�K������G�����$&6�\	�W����c�/!��L>?K#�h
2���&!������(��N}�T����keI�A��G�c��f6O�3����sy�/��OE�RZH��W����WSX��|~�:ZL�/���,�6����C���o� ��c�%��[
����?�
��+i�o�\����S�a����tm
�����0���D�,�*���}zb�Fn��_4N�r�L���}I�<�g}\o��_7[�>.�����$��Z�m�:��f���� l
��p
��!�����@����C��Z�r�pK�v�7��������+�"%�%���38����m���1�<uV���=���a�4���P��{���:*�l�g�p>�$X ���) ���z�(Vl��������0��Dz(@&��q�Q������!��9�mX����vr��06���RrZ�����i#o��A�
���Nc�o�D$�,y�I�{����x��������-%�	��C�e�V�v���`[�g���'-�"�&W���%�Z�fO2����9�v��x&'
7&���9;���%����T�~R���~��:B�S�o������@	)c�S��e��A���e@�,�������>�[�EK�����X^L�=�����{��fV(*��_���r������Y����r
�����|� (q���o~X�SnQ��~1��-��m������^A�J|��!�>y_�MqXw�)�Hv�Q���N��x����c��[��4Z�������LG�Ci�H.�jG2����;F��0I4x��+>��os���w�_��W�"����� }�b-E����m��3�V����G�i�_�ir�������V���:&�r�0k��YVx��
A�\��B�j�bR2����|B6QR��6�n?�����`h�obY_y��X��m���}o\�vz����$[1��)g�f)`�W%��)�~Y������l�\�����bu���0����e����mY�_P����~I
����k�������lia6��+���2+�z��+�
��g��eK��Y�u��	�W)���=Q[D
��SU)���'���@e�������um�
:Q�!�2��E�&���'J�+��j���G�0/h��yp����G����D0�%5��V?%��+8�����S`��������	ee��y�g��e��a
�D;���$[o"P".#yj���Z�=?�������8����KVk]���h�����K#j��iK����
u%���/�=��H8���W
�Va���K�Bf��(�,��4|g1��;���YjTq�@����QH�L�q�J^��j�g�����w���%�� d�.���������#Y��	��#����'��Avt��Ero����2�l!���&��o����{z.���g�$M��������.�[�C��g�g�x���w�[�����
.~����d�'��M�W�l|H�f������x6e��
m���Fp���F�Z����;��W����0��K�klq=��
G����N&=]gc]�`�R���7Q�3cm�I���A��z4����m�VHc���"�F�Q����c��gg�i���pl���z3��i��3*�b���w�������t��*��r:����a�����$�����5����.;�_G��L13����>�� G���(�Y��-�e�!/�9��f����x��<g��;9�r%����w'�Z�?����"T��������Z��	`�vgQ�����(�	���}
����Q�����vC��n����3x�j	<%��~X��-�"������N������
q���X����9X��+y/?Is]�y?�pw�i�i�b,���#�"��=�����buf����6�}����m6��O0�cy�
KM!����U�z�M��ab��2i��A`+}5�wu���W���G��3��������_��{����_�	<���.A8Qx��1�a: ���e�Q�Q��C�6�\�@/5yq�x�Iu.[e�g��%�~�s#�����E^��{�|
���������=���r�lYg�t�E}���s�������fQZ�RW0(A��^��H/���|��(�M�M+���^5?��*�U�~��W���^5�R>�V�h�%yU�mL-���xH�X��>�\b��e�+���{����g���qwtKn������h�x�}�}�
4�9>N��������L5�v)�%���E���J;�G)?uZ
�4u��"7'�����3_�),�<���7�����[���D�l��~#�3����LA+Ag�UM'�������}�m��f2�5�_\�� �X�����Q�X��-�R�)���_{�kR�_����q��8���0��o�@�������*���L���O��P��_
{���{�����k��^,�I�U-�F�Q1�l�U`�,:����(h��)h^?����)e.�����X���O����$��t�����/{�x�Vgx�&�r�5hd��E��n�}`t%F����/)[�D�*�f-��9�hN�te��y�Y��]�n/������X����k�VK�
������L���+�$9iC�����F��yO���\LW��(�3(��q��_F�����w��!z�D3�s��ZD��$�A�T� �"�7�� �x��e���������0�����p�
]]����D���l`&��
�����+_�N������Cp�\������n��Z$�o�#?/���>�U������?�����d@���x<��?p8���p���y��N�I���c��[�E�Ih���M�������~a
����J��S|
�6A�T�S�!p����N.�@����f��y�Td�Kg����(���x���<�D������K��� ��y�����00\=�r���6�5�l+a5�����Y���h�������N��@��)��jN���D	��(-���&���F�����7(�}9���q�&���ifg��s0��v4\�����/gj��=�S��]�3��?}�f��a4�E����I�S�{��?s�Tdh]4tw�,}��cZ�
h��D����Z���^�����L�s��.�W������Q�[A�t��	�7�}$��[�=���@��j��Ie}��D��~�^������w�'?�o����I���RN/�5Se����z�X�d������MnE�S�Utw�����E� �K7�}�uRZc�<(��p8���2C`N���� I)�5Zd|� ���n%�)����/���.Z0��27�^^hM�:�%����0��}�uL0�?�XlSz���Z��L����5�w��-��/M���"Z�/��l6y��%G�3��8��Y��T��>��{�`T���r�uci��g������RvCK-�Ny��v��
�R�\'^A��x_)�$Qtq�7�D�s�bBic|g��icl��<��������oQ���Q�*�s�H�Y*�2;[�&�� 6���{������;d���������wB�����eA`u5jS����6�"���(O>�zY�����������"�}kB6u�M���,h9C?b0,68^���W����$H��w�"���p����=�����P��%9rOJyRJ�an�R������B�����a�����NQO�����i���kP4C���p&(yV�L!��G��L��^��{���<�F��,�]Jeztv��la��������#U����2���]���)c�8�F��m�n 5��k�M*SV�9�������2g��~�]����'���������Z+gP`�6��-��������Q�-��\����	��= PJ� �a�PxFP�@��fn
�:��)���UW~g���l����k-e�oXz�(�-%Tnt	/�2�������O��G�F|{B����V(|1v��) &Sq������d��!FI%]�8�����=���N�����FC���I�eP�m.M2
CuS�(����`��V{�LO8C��L���F���
���I��+?�G��0� U�/�A4��:kL�A]��I�%P(��o�}���ND��f����
��t����)MY�e)q����������eP���k!������U����S��?j@ho��P�T/��<S���%�Z����������^�Z]o���i�k:�`e��o�����w����7����U9:���'J
��_8�,X����HUJ�HHDG�Z|��E��p�����������>���6���4_k8��$O�����GbS�?���n K`��&F:�g����oFD�	��L>����G'�j���"mm���>,��>��NW���,��[�f9eWJ����I����G����}�t�:�e�PN�[����>0����cQ������$�N�?����6�r��]�y��;y�����=�4��o�q�>�?�?���3i��y�)���F�U#�W���U�����)
�����I%����B 7
$�'2��h� �5R���d���3�v�����8�9�Y~��Z}�����N@����N��2���n��F��uo*���������.�}.�}�8K_2����m�?�1y5����]�Y�'J,��~E�X���T(�����z��k$���CY��0J�Q������h]��{�c8���1������#������D��Th�4���������>$��1�a.���������������Vjbn��p�M�F�gC��//`i������P*����T2�����BY�4]�@8^�i�0]�L���i������H���T���G�|���C_#RA��_n Z^i���������S��t�3	���^����!�e��Qk]���-������6���F�d�����Jm����<��R������e=���V�Ph�k���%������2��O?u�o�]�:�gV�1H����w���U����cu��n�C���_`O��T���-��������n�����~��0��v��aR1��|	F���wu��@<�p��Pb?�������o�M������y���$���2r�!=s��1����D��@� ����9A��D�s���"�`�	-WM��3�	���p���B����m|��������w�Q������uoF�h��9����J�q����&��}����\-�	;��/�v0��w�91�N�%���v6D���*:���5W��E�3�/���?��60k��f<V��XV�������6����{10�w�Ff���^+��`����Gf����k������{�P=�w�Z����o��Yohr��7V�*�aJ�{�K�2r=BT@z��P8��E��:���N:�����$��_�7�������^/m�N���ofZ`��$�)�P5�����A�4��Z�"b����.9!��+�c��M��I�������/��)��Z��;����/2���������J�J�5������]��Y"���*$K��0'V�Gk?j2�b��fE��P�6���W�,"0&�f�������S�f!K;���t���8�Z��N�gw8<�(:s�����4:��gN8h��$I%��(1Wy�S�3i�V�.@���<k,��u{�!�>�-��I�+�����T�y�"���6�Z**�
����{�;�ue{uA&��SW���PT�\�
|/���+�\7a$T�@l��
����KO57 �0�f*�i�����IK
{�1���U_vcE�0����1������T����cq���x�����S��������;�@�@8�?��N��/�kyv��V�H����%��S����c����`�{��} �%�	B��S]�	(9Cl3�\���c	��a���" ��W��{)t���0@%5�R�:<d�l�m�T`��f,����������"�-�N�e����-�|9��Q����@-�
���uh��kU�`U����W��N���`���Rd����(���R�\���R�G<y���I�X����6�w��pe����<�����J�Ko�����v.6�}�����"��}�P�i@�4�@���<�;\���e?y
�g���4S�B�t��$VTc<�g*b}�X���<lXt�L*�w�y��?j������������04C�y�1�{�*��d:(��rA��NF�tdI���l��Z�?��s������8�*��z��<�|r}�u{lzk�_�[F��,�<th^����7���Uh�Q��-g���A����4�t����9>�d��]�C�T�c��K��1�8u ���I���Y�� ��+Q��ZK7G�j�4���5���Z�V�P�
%e[�*�d0
d�`�W-�~�������<uHB@���G!O�3B�+k��NR�=�7�A�H��s��,d!)'��v�}�g!�w�V�u+�02��.�y�
�2,��!�Nc1#|V�������F%��_)�e�3I��h���9R2�I�IN}����0P�P0a���:�2aS*�W*A�sY�D�dlsRW�'�s�����'s�i��(}/����}�j�P��1���2��?)6,���������4���\���%L�����o4��������^c]�jl�w�����Q�V�O7�lcck�3t�T�n��)�'�dd�r%M�(��U�B-�d��������I�OL�T�RS�#���O_\�g���e�S����L�T������V���\LU�5����-����jO���2�UR \x8�^������;����<h]�W��l�	[��:���|/��?L1�}����y����P��=�w��a�wNq�|��-Exl�~$�K{Jag�Q%�w2aWn�RsZ>���rR����K��fh������d�������V����kr,���}�ec��\j-�����	!7�l��k����S�D<�c�v��B)��������;�����)�H�]�������z�j�E\�����y��z��^<�]����-�S�
K������/A����7���Q�(z�t������_����h���������F���Wk�E�)#�=�zU��+_W&�I\��
|��(r�_Oy�9�>��%��M?��u��e���cz��x����4](��ff(96"u��y���{]
vf��R�5��}m�!�x[�&���Fo��h�6��7�|"T��������E@ �t��z�q� -��Dtj������2������%K(x�7��nzb����"��)���#t�+�E�5zf��A�"C�p�DfW���?Lv7�(4����bD��c���f&v�!�t�%/�DC��������
���u��N������j<��M��A�`�����8I���w��"C7���6F�)�
�.s�\d��=������Vtl�j�G�����6W��%���?�[1��5��@��������F��'F�)����M��A�
�R����0�E}��]�lL[��8A=�g�i�P�/���/$D��x
������,=$������a��7R,�ov�\�~���?
�fA��9������Vu��G`���^@B�����i2S�]\���`[O�_����6$���I<�����Z��#�����zcmm���l��F������G������������@�}k�VoD+���z���<�~��|;Q����9i���#24@r�}���G2%-� {t���������!|�R���y�|������:���S�ZwW���
�b�i�k<��Og�����lm��UP�Wi�|��5��������uw����u)�+��z�����3��7�8Z�����SR6].�K�7��|4I��C����d�/��Y��,�[�`O��6��q�T
��������m��%�8�|���QSA����p������WV�9�'P9�E���S��=���_��wH8�����^�V�#�����5��ak�Q�_�d2��N��	�g��\=�C�h��[�s�J��c�P����	�iE�k4���/~S5�0xV��aS�����Q2������������W���	9u��x
<��]������d�l/�S�W���T�3:�*0���o�^��o����a�����U	��]���U�C|���KFFT�����@<%�������A�J�Qc4��3a���tU��e�B�Q�_����G���i�I�U�s�m��M���6w�p�����O�I�1����Tq�U�8�,��<�Y�k�6���xP!<�f�T���NO�LW�F��S�D;�O�i�X�_k���M*IT<�I.+f�w�=�{�[�Ou���I��g�lz�D�O"9�g���~\}Iv�b��"����tt5�
<��j;JB$mpF�O��������j��^U���W[z�����B[z5K���j��^
niox���j����n���o?��`���n��2�o�G��~P�m?�;x�����!��������������S�5�_h�d������md���t��Px��g�=��+��hc	���j+��R�Wm�����r������+�%3`HD���}#8��V� >�����	����N��{hhCv��������d��y���a+���(�3��v<��d�]�������O�o�RlI)�Y����C�jR���t�G�Y��p�������������iU����?2���/�Ohtk�l)�+�G�H�VR=�*��U��G�����#zb������6,���(a�<�g7#�c�aR���q/<m�ff.� �7�LP�
�����>�V���L��,�R^��A`����*4��������]���V_�Q� V3Pu�~�h��;�w�����������N-�d2U����~@�����t�b��	8��cFW�E4IT����:'g]�6���������WT�������
e�~�(��q�3�m"^i����L�Z1Ma�8��o�9�G�h4K��P���9��;goaR����5���k�����Kj�]V���0O�D1N��
R��:n&Y�C�T[@{n�Lt��NF��Z��?���o(*�����Wl���eA�D�8��zS�S�{����O��~F~�z�Q�*�SE�9��d��F�qU=>;@@��������M���v%�����dh�xi	[���`n���!�Qq��T����%����8j���f�]$��oO�s��{���{U���7������j)5K����"va���~��\����:HQ���kd�8Nj?����Z".n4�������d��=�\ltiR�Cw_?)����uk�
���>���|4ZY	�:��F�b:�������;���Y6�j�!pLev��g��`�4������G�a8�QE��j���%���a+�aO�����4��:/����W�����<Duv�?Dw�Ih��L`��,Q����a���Z��Bm�A���sjk�Q�:o�]���J��Mpg�����<�����f)�_�)	�1�����H'U�0�j#	���1}Z���L9L������J��{V�A���������W���&T#�xe�j�ey�H4<=KA@��/<2a�9Q��^�i�{�^�V�q��%/[�����U�8Z��Q��W��
�~e�k3�Sn���r���K�Wm�E�]�R-jXI�]�������Nr���[� �����x]E�W��P��o0���g�v<�s��#�4��D_����������Y���~i��n�H�@#w����X���#���5����h���FWR	/9�W������M��a�`��z.E��t���I�
���	;{�piF�����Lb�
�p��4B�fu���6a�5�>E�����.f��b��iU^>k������ETE(��b����T	��a	�L��S���8Ii��b�	���0=����_�"����h�58O���]��?������YJ;)[R?W_p����\�n�@��g�7�����)�_�j*��o������\���_�M��a��d����Mt�S��SJ�FrV��;���V2�����M���.�*kj��`��[AP4I�1���LH�<��,��!�d-����r�g��,Q% �f�}�'p�#�yQ"��#Bt�y����x�����#OB]�@�i^�z\��F������S�P*�l��
VL�����.�}ce����f�����PR�a*��h�D3�������A�E!O�������3gs�����hi��gx��LW��o&3EZ.&�<7�E�ix���(��.�:��%.��^���zl������������Ns�\�R	�\S�}�vj�F��>6����5�!\Y��$yz���S%<zv�\a��%u��R<���^����V�b�
��B%Ou��<m��Q����_�{�
p!�����j�z���oX�$O����-����
��
�����v^�����:Z�m��nR�q6���5.��v�l�����i�}_��`�
���&�g6�]���.6���s4����"���h���D��R�h`a�?�ik-�)z����~��E�����������Wo�j~������e��/O����f����h����/��'�����]H�~��6��q�ZQ97�:>}��|�<�����]c[�u�>�o��j�����BWM�S������Sa%:<���&&lI�Zy�
�k%��^@S�USt�+&��T�����K0��ae����
�p���w�
�H��������
�N�J���}�8������|}��R�:��*U]|_}��+�����Xod����<�Z��������6�y/���W?�����]Z`���+'����`0~Z��y�}���v�Y�u�%-?.�������Y\���>��w%�HS��Q�+t
L��^���:��O-r�M�\�y��oC^l��4���G8GQ����
������`V-�d�^��-bkyh���\��*�5LK�������8������k��#v��X���OabWu�������8]�>w
�u����l�����>�FL��<������.��0v�/8���gr��2I��� 6l����T<��bj:�)D=����Rx�I4��G���!�g��P�z�����&.C�����u��Z�����3���+���"�r�1��p�W�vh�����	6����{����Fh���qO������h}�4���FU�-���2 �&���L���9�
��av/<!>�6�#rL������/�{�8bo��iu�������/����
U����M�QKs�:�~�=��C�c3&A�Q��R�����>q�]�^������?fy�OK}�hJ�|�fQ�^��.��t����H
�:!�9����wM�+j����,u�7Bz�(��"1�>J7�6�/�i����g����o^6�2
�x��(z���*�k�y��������KW;k�8�(��j��N/�wAXJ������-�&��'�zF)��3���w)�|�So({�����FT,��E�]���*Q�gS
i���i;�����a6�1�^������V5���2����pW�^v�NN:p�Pq�}����bd6������'R��Z���=��1PO
w1��f2�M05q���q�������CB='�:�����
�z-��2�\���mD+���������R����7� 3���,>�|���i<��=����x_)����6"]gZ����w�L��������$�)����������8h�;�����l�K~���C�:����o!8c����gWx����Z���[_}���w���/����R�^��i���%��G��,4�|��7:����;��f�6.��	j}r�g7����2^�R�mCJ3^7W����w�'?S�bu�x�=JY-�������G.�4�!��c��2�%��CF�/#M�t��(�h�9� �\�N��6������S�����[�v�W��,�M����:�8�zGcCq��Z?F*�
(���a_��|���R4N���/8��/�gh��2��a���bz}�M��G�2��5�7��y�a�u�*v���Mm�0��q��#���Y��4WK�i#����������Z�����(� �#nH`H<6K��A���z/4=���	��'��2h����*�=PZ�4�Pr�|��pN�����th�u������f.'�l�.!��S��t��hX���[��*_�*z��
��g]���B���l��N�m&r��JW��ABC�Y��>�M��rC�p���g�KE��x0��r��h@�@?s3�FjF�.�&sE����`�h�F���{W1�����Q<a��a{D�����$$@(I
��
�q�V��q���~��K�uj����~�#�1��5���Yz��c�4���(6���dpu]1v������?�u��R���
?;#��^�f%L�H-�:�&,'q`��=F�DGR������������!z��x���x����)n��lzE,�:��
���(��'��)�nlt��m�����i�!�T}d��S� ��qnJ'���3��������	���FI����)^��	�^o9���4D$7��8(9�$5zb�����L�����[�+?�.l��9&���pm�D��7��aR��J��K�0K�<_j����ZI[���*�;`wL�h� �W� ���F���o��C�E������N�{r|����8���s�,����"j��5s���{?�@@��a�V��u�^Q��xvf�)��0�"���g���}��H��A����R�N���<[��R*.��)!��X�B�S*B(' ���C�q�/E�c����>���g�A0��7�f�m���9]����`e�����T����L����3��}��k���E������p��T��VQe�j(,�S*�N�M�&`�Mt�Q���?s�iw����k	���+;0l.<:O����TG�:~H�����).m��������h�����@��:k�GD�sQ�3Bd�������wD��&�Szx#&���������ZLFkA�ZT�bD�	L���jn�z�X��^�&���Ti��Q�Z���HM
��bQ]���*�Hx4�L8Z�h:ro�gq2��
����24��h��)���ssq���:BE^~�hJ�PdaL�J���A5|9��:�*�|�� 7�J
+N�]EH���������&��'��8p�+�Q���T�}�	X )�<���S���T	�e�8��)1�"g�2�Mt�7�9������n�S3
�	O�d4��~��$"	=���id���-�������;�D���m���T��9s�F`G�dQ���
1�3b���dNb��)ef��ZP�YG���~��9�V��	s:�|�j[_j���}�uN�9����3(7<l0gz}k:�	��$�������~:���t<������#�����K���D�NUq���� �@5������8���)#��C��~���R���m�,�h!��U���T<�������s$�&������]���d�#��y6��C*��@Q)�z�� !E������Z@�h%
�U;��;[+�z�/d7���vE7��������;(9+B��q0�4�Qu�>��0���7Em
�7+?��2�^%��3��o|�/X4�q������NL�l5�{��T�HC*G~�pY��U��W���������D�E�1��F��V���:^�b*A��s�&4Y�?��+����
8PPW���E��9t�a�1�5�����y,+X���l` �\���3������a�����o)
����Hk�tM�|/bD�[�/��6�/�nv���:�~�[a�R^��s.k,--�([d���fW�>S
 j==Q�#�@Td
���r/��7��\��Mo��T����%�5SI��jr���h`m��
����Q��GI�6�z}�+`�(��f
��|Q�
����:�7��8>>�t_6����Hg��u���F�uH�g&�8�����7W�x�&����fa*�����{�����Y��jg��J.*��Z�7�lZ��.�j��	����W�G$����9���	3���s�>H���.�������S�yE�����{oeD�ro��S���Hy�7��<���:��*������eN���������oM���ZJ>�2���e�����-Z�E�k�����p�_��	�*���7d^�jT}�UB��(�@3��d!�/�E�%LIXMx�]s�����B�5E��O\�h���J�N8��������
�hfL���4\,�H:e�xj��ag��	Rf��$^�A�'qb�J����G�"�\�=�C���Y���8��Vo�����(�W[�v�2��Y&`�c������*��G0-�j�����|{����D��	1r��2�,�"�&��pOjM�e�����]��A[����&�r�iU��d�������=��E���W�����3O	�uF�:B�!J�XeT-W����M_��`Bm���B�O�F��	���s�z\j
�0�L��q�)�p7�oq���3�p�Jp��*��<��<�T�W�����4��<a��>��f�������)j���8k=��M0d^Ps��
/i}	�r�����i�5`�<h2F3e�H������0L-0�J�Q���bq
����%��;�B$�=Y�e��<&����z��#�
��cLD���P�9�r-Z�7������tn���ds�U�<�\s"}��c�1Y��>��rh�!P3�z�I�����7q��'���p'��37�2a����f
��Q��>`D��\�3�r9DF�o��"�����������c�G�����+��~P�(?�XF-�:����o�l����a<�����e���9�UMml�/0~���ju�G
������tt�����rV��F����x�iz������39�4T,� 28��l�AaN�.��Q�]\���,�cW�ev���1s�#=:G�������;�N��
#���rl0���Z>������`����q�klv� �Bz��up��{���������J'`7x>
(0(�TqFO@%���$�Dq����b�h;�'���b�C�6�*�+�P��O?��#���3�:89}�5y�Z�����)�%k�&����`�0��B!�ku�
�Y31cs��0G�0O0DM�$$����1hJ��D����40������0E0�SQ��-�����
����9*�>��B@!#�0Tl��X�E��#�2c�d@���Cl�6�7������,�p�����f�A�*
Q@�b%/HMN��uR^��U�-Z��xy�2I��"�af.�S[I#��~&T8��.0�@h�t%=�������Ozu��r��X2[�[+[��H�B>�o���bo�I������lSU�i�J��oz����H�f�V�����X�q�}���[$�����/���[-�>P%��������8Lz�x
1����1~���HM*�UQ���Fc� &cI.�������A�� ��
��LI`�#	)���	�!_�F`�::�$�7 8�oA���	�B�
S��1U!k+z��� �
F�t�$
Mw��z!��m8]��o����Q�����_�[���������.:��������D�0����=�<����X&s�nV��A���B��W��d�2#Pn�T���X�
��Bm1�)]$x�F��"�C��:�YZ��va����q)��z)QOd�x
�a�]dv��4�p0���49M�s��9%t���� :�2 �R"Q@~��"�k��I�X�l�,�d�F9�f��f~i����q�U���0��%���J���k�uA6��U���?%����d�+M��K�s
lA�Un@=Vl?Y��|�,k��:���\&BDo��08���W_��ak��	��{bU[��)��~]%����>��q�vN������������N>x�'>������s�H�aeE�$K�d������&
�����#�z)������d������5������=�A4N�S�e�k��� ar�s�����[[���&���S������1r����:�{�JW�j^�m/t
�
�����y����DF
�R��JV#��0�{#Y���]�j���5e�����`���K����[��&�J=�5��/j��@�j���)j6���j8�q/j���f������W��?NP�6�|Tf;�Z,���#�����+�����m=��)�E(�Z��!�8e�%9���4��I�4�^�P^#��c={�!�P��f���1<W�z����^|O������V�p���������n2�� ������22���"�����8��JV`�^#>���X[������"*��,*�0�
L!�M��X��
U������	���y5�������6�2��}f�N����5s$�@�gE5Jq���,i�<
�������������H��pq����<
,��y��9��L�2��iqs���t
-��	������PHT� ��[����t6;�lw���Js7���S��9i���9�2�� ����>0���L��cC������q n�`�5�I�lJ�oAS������W�2"��l+Z����*����,�,Y�5�1K�������V*���9�H�����C��b��4q��s��������v���Q�W�_��l��u8�f����l7��|��r���e�������P������N�Ex����L�$o����7s_����q6�����1��X��������q�ime���`v������UL�}�c�0���%-dJr��w��rq����'����J�
��vH�h&-h���x��~|w������e�b�v1�����IQ�rv0l����,C�����%U����i����K��X�K��Kv��62`�r�|�����9����P��2�6�������U���$��s/i��~����LG���$�VT��/&}�%����d@{X�V��d@�W�V��dHV�Z��d������K�LSQ�9BA�����+�4�R�R�4K�,|y�>'
��w{�Ad�m\��n������������w�io6a���ap��
��>�N<�R+�`��u�������,eQ�.]���������p�7����R-]a������Qd���5;!�+�D�����J�]S���(�;����^_��
z;��A���l!�JR�:@g����H�����&������"�=5���(��].�R��P)�}�KWl��|4N�r�B�U*'�	�%�R�?�<�oA����v������7���:������&���N��Zt�����A(/�����q��#h�_
A��s{����s���Q
�E�;��R^�N0H-���:������=����e�k��i�/Q)��e��-����x����K����y�u���"�����������EeJ����!�Z�J(���;���O�,���������_)r>w%|�^�B�,�����/T��I<��������r�k2��E2�_�g!�]�I��`��e,P����T���~#FfM'��<�,���� E	y�������+�osBY+.�Q�=u����&)���N���U������A�m�����W��Y���_�hd��� ���������?jv�����i�Q6�kb�:��lu�%�5y����<"�������3���X�=��]8�
R���V�8����5���P�@�D"�H�|N:���N�Z����U�I�9	Y#Rd��,�X�t���@k-7�J�����(��P@���$D7
��LY�.�S���W��pl��	sl��9��~\������{���p��c�-dql���Z�8\���\�V�E7���6�
�o��a<S���e���N��r_�lv���%�*3:Oi��X�������S5��F��C�����g�s����nr�b���g\c�e����c=	w������uXJ����*7R+T}�~�F�JXw�����FU|��]T��	DnM�
����?��u�1	g�/7�x�u����pk�^�o�=t5�w�! \�����!�CL�f:|^���1���^������N���%�Q�~PBg��p5�*���B4����)��>�4������
����Q����t��X&�p;���6��r��A�Hh�PH�� 8gCZ�xh(���u����z��Tl���1E�F�������~��7�����I4��i7�����;�mM��"��D��X;�*�>tl������5��f�d�+E�3sI��b+�;��-��8����s������X��m�j��&I)����b�:��*j%�C��v��<�@NH4w�(�-����������h�)GpDj%�V�.D(�����dO��_K�B"������d�u�^5��w�[�+E�R��V�X�;��C��I�����S7n���.�����Z�0�G,��sL�J��������}!��	be)����4����,B��)�s�B�Qzg��w�:�������N���f�b*3Li=Sdd~i��I�������j���.Lb3��.R�d2���;�	���5=f���P���&��m�����F����������d�i����OG�j�9V���h�{��s�S���|��O���x�8}���u��p�jd���6s�KIyH�*�����<��5R�]�D/naQ=�=���I���y�1�8}�%�pw(�q�e����p5$��8)�K��2I�s�g�UhK.�^Av�n��v�e�P���"XIr��5�IF'_��AosnS�7�;X[��D���l*>y�v�Y��*�o�f�����pL���Rh0������ih���s��������,����d�z������
0?���n��o�������~��	�4q�q;�E���������z�aUf\��[����m�vB|����[����XMB0%���N|�����l�z6��>CB�g�����R[omi�f �?�������z��&B�@&��d���^����cz6��R.���.�$��7G�xh�Q����_�w jV�j�{�56/ii����~��+�S^���us�t�	�����(1��q����fn]���a���1A��L����Yf��s��,��n`�G��W����#��E��v�5�+�g�k�jJ#���o���$;/���+�54\L����Z��A�5_��BvxE�	�w?R�K�)�]��5[��gr+�'v���FX$�o$%�d	E'�9W����-�$!���D9S���L�����t��V���-���a�!q�n�!)�m��X�
D����RP�^��ad����&�a`�e$����&������EBOF,�
�D��5 D���X�	!��rMh�������BOL,�2	c)9�|F*��6�y^�)G>I��f�o�/'Gn��7��R�J���.���cA1;���k������JB{4���"[��v.Mi�RRY���Y��/Q�g�������/��>0����:�piP�(��2YC�����4'��T������Q��>��P>����;��G6n��"��[�z����������N����^t��&�{�����b���T�{f�������<���5�],g����/+"pw�'�F`��oS�;���b�������_��=w����}�n`����3��Jhb6���^��E���oZ��V�c��c:x���/.1HW���/w'	���F��.�S��S����Iu~e�(�;��Oy?��=����~9�H�F��;��*��-��D��:���kH�gX���o����������3�b��	�/|u�37����M~���H#�a�����zU���Wh��F�����s�)������s��x0*�����������������������W��(Z��_U��s�����Yo`�������o�B�59�F�VgE�G0(�p��x����x���TN<|f�h��h��6�}`Ew�w���2l�W'go�;�|�AU��o�8����]GCL����A���9��d�Kw�6�U�d��q�|����g�����������u���O%��N*�~�Ll8����+����|������8V��t��r`�=-OO�3���j�:'g�34��#���S%��T`��kF��������*����������voC��j��5[j0�LP{H"��p�w��� e���&�H6,�R��d������WF?.l�$
6M����%b��k{�{r}wj�[L>3#��Sq`3��(��vjV�`����I;��N����D��&�C��c�(}y��\�Q�����AY2 ��
���A^���q6��}N�������N���y;s��q
�eC��
e�4	q
�,����2�5�8�}'h+�h}��t�S�c��Q�
���[�ml�pn�2���@N���{��'k	P-PZ�&�2��gV�%�Y-�d��]�-���r�x�rKi.�\;�;��,��\�)��R��)����XJ��Z	Lm!I���e.	����R��e�GT��^$g���y��(gI{���v����w�z�H��-dI��������������P���acWIF�t�o�fw\ Q��g�U����8k��Q|�N�#��r�_5G>6]f��*�����#���!��	Y������;���<��aQH\����\nb�f�'�^L��71?��?1G|�����Sn�-
%���g1c���;`���S����_�����/��:���j�( T?�.*�h���q/�O�K^�|#%���a��.�2��LH�,�7��e�4%^fU��e	|��-C�F���<��2���+|��a�D8��+Y:����\"d�8C���P2����!Rb�9)Db������!ew�K��rg�+v�eR�L��!�3T�"c��J���o�IB����%U�r�����J����[Z;>��r���7O�f9;z3M��[��N��{�C�H��������C$���h�.z�I-����dz�G��.���X�\��(��Y��UI&����m�����F�~9����|WP�6�f��w��,���uZ����������7����W-nY��V�iq�Z\�!��������bRmm��e9����=Oqs���l��������<ef���@5��������4���a,�1��n~;p���2p��/`��Q��S2�81�C}������{C��
�E�tRD�w��k���.����n�S%�Ws�����H����y:P#Q?S���z�7��]����Z[;����<��S��RZ�]5��m�����*t!�F7VX��5�V�q�h�R����
�o����+�S�~��������@.i��N�Y��n
���m62��}�����W�>�:�;�����2N �G;H��?�s������t��)��;�����7����;UO�3�o�B"H��t�~�i�SV5F������[_[���^NZ����0��J��	�]0�H�k<�Q`y��d��(Q~��X<�x�w=��^��Aox5��<���G��k{��(�I�f4��&�<'C8H�%�W3u��s��W��Y��,��]"��_z_��`�|��J!��^��"R1��-�q���k�*D5�������ZE��U���&��W��vn�>�"KK��z���X�����4J����D�^����{�.qI]<������( ��^r �&��3`$$%���j3VP����^A��3^:
�0D�h(w��G�d�^�Y���L�o��j>�]U2��Ud�d������q�q�g�
��M�xd��H�mzA�o��x;��h����1.0��>L��B�!����6��Y���G���k���5�9#�������t����i���%(��a����
����u+y��G.�u���j$��=JZa��y�����p�������:�3\���{�Qo2O��y�r��	�\����EK���F��K��~�*�H5�����f�	U3 �Or���*����lpk�D����I�;G6T��|�S?��)$��6�:��k���a-��"N�U*:���V������X��I������x�5LRTt�0!������r�5��o�������N����
0g�XUb)H��^%���X�N��I��Y������0<[�e&e�2�7�$;�� F��F�L�fE��f���8��R�g��7�
�)���	Hu���\O���?i����4C�#����tNO���A�����1�0��f���~fz]J���o[��Z�>+.���Ap0�\lU��<�@g��2��7����d
��=�����n=.�)�c}��������;\?o��4�o�y|�v�6��P}�>Qk����������M(}f>�z�����_���G�I�S��������O��u}��������Q��Y<��\��7)\ItXt�A����-=Q����'�P�l:��hi��L}�������#%T���$�c?u��F��>���}y������yF\���NTS=�M��+��a��������jW�(Q��U���[�u�#l�$�@�c��K��;��n�����z�l0�n���0n~�v��P���:�va��c��H5�=O�8��
�PD�����:���e~z���(�\�/#���fN��>�q���Zl)�6S4��������6�B��}���\v
��RE��q���������%�'��vI�K�4g1��@�,����j�S�<S�j�g�z��&�t����-C�z#�����:-w��w=���T7�U��U������K���g�!�	>�O3�	2���i�b�����U�Ap���q����yf����SH��s^�����B��1�
mS����P8:
u
��
��Ea$O�#A�n�6c�
���d>�����]��:8+$����>74R����M�N���Y���6���o�P�m4�#Zq�
����n;f��:���7�g2�~A/��t��&M	H�����(�K8�|�O}B��rB�`�S��.��P	�OHq� ��Q�b�"GFVV=�����������bQ�6���!�����D	3),�%��%���#w��h�	�������'E��
�L��(����,���?\�4�`�jlS����������������FW���G@~TuT(F	��8��h1[a��h8���X�V�H>�!0���6d?�2�	*%���h���Bv����U�����W��:�#�����_	D��{��<9�tO�g���m�	_�������h����i���:�3���F���E����_�>k���4���#�_�D�QE��������G��M��|���E�gg�����>�f���u�n�^������y�����}����?�>�Z/�B�o;�������,Jm7�:peg}�n��$u�F��`���y�>���M���WG�����V`;�v_�M�=��B+������jwZm��y��==i)0)���'�&�x������5�����#�?}���o��z��
��?�A��������=;S�G�������g���WG�x���y���;gjB���MwT#0_��u��I_�o����~�B����"��8D�����!a3z�=���|v0o�}�`K�������������m��o�����[
?���7����6�������xwp�$���t���-��2�}��Mv�B����S_��/�f�����!|*0*�����}C�=<y�� :<y������
G��j�Hm��17�<>89l��/g�Na����X��
|��NU��w�?4O�����j��'������Y�C�G5���8=�="������9�����l0���-1��~����������/@����"�0�W�oZjo�jv�<^����j��a^�����'?�^��)����N��MEY��X�Wg��"���N�D��*j���1�n�����z��"��4��<n������������}9�q������S5��������[��=���Z}��K�X�������{������6XK�~E�
�F�c��i������M�gg����/'���'���j����D}���ku��u�����^�NI�U����1	�����O|W��-x����3nA����W���QK-�D34�w�w�U�7R�����).�����Qt��������r��QM�Ps�?����k�>�;=;9y���5_������w���"�����q�0�0B�LZ��:0`;�;_�[:>�D��oa�����|�������������
�P_�����������i������Nt�:lG'G��Z��c�_ONa(z~r���>T��7�*�R�trv�pL�m)������o:F'���o��������s���/������w�������L����Z�dk>������'~��AG�Zm~��VmA��t��|�/�7����Z
4����#�#�p��R��������\��7��:�Zv?���	�&��_�eh��].�9�?���/���Out�8k�����PWl���f�4�l�����?�O����R_��A���o��T�G8�����}��b3�*g�A���0F�L��A�@�����oU1�'����}����BQ[u�C	~��N~�����GD���7�-%��?�������3u2)
x�gg���V�Rk7ER�0_��(S#�#������QSsU�����,�o
�����(z�M}�B3��T�o���=V���������ac�	����Pqr�
���
���k�o���;
#�/�
m����BA�;�z�Rg�B	*��w�4��YtG�Acf��@l�A �U.Zj�}�`�"�?�������H��w��!�U=w�����6�����)�U����_���)�Q��"��D��v����b�PX�HM��b����
�)&
Gx"�a1
`|���%��-s�o�_��=�S�c������}{�T
����!G�+x-�\����t��D�	*vZ��S�%OP��~����7��>�2�_��_G�D�?����e�l)������2������byd�&����8����F�KH7|�Z�H55�a���KH
���������8����?�:���Y����E-�k_�!��U��5R�h	xx����iOf�������"�W#�����������\�&6-�N;�����*���1���l��T}�K-j�Ng�@Aq2��E���8�U�]\�WP��u2���d:Pd�*K�V�j���/��;B����T��%T��KK�X4��`�(�!�����V�V��b(��Hy�9�6�m�V��J"�&���3��`1v�z�@��1c���!��0����hz3��yN�E����Y��#Y	vn ���)����\�%-��B|�)�c�� 2�I��T�����8E���C���D�X�:!�5�U�6�9B��f<�����:�����a|>�������H�[�z��������'��S��_����k��*��[��O$��L��j1���������E��u������U�'�a���4O$��!J�(�A���K� {bwg������{FI��|(�����c�8������c�V
�9�������G\����e��!0[[�RWolop�B�����,��/��j:�L1p��04*��5����g�����5�KU�3����_6j�o�T�l��1	�/���/�����Gh���1m��Zk���{*@si�~���H����x�:&+��b�oZ�f�����y��tc��_M���Z[<�]46S������/��n��N'<-}�m�t�F���U���p]2�6����W��N y������de���PS���-�`���#�g7�����F)~oE�����5���<:}�1?^��(����xQ�r Zz
����c��l�&����I*�)Tg!��sE�L����k���]�6����q)���������mn�z�f<[Z"�%�g����n8�~{[�'LwZ���������^Z�+���v�z�j�\5�6������Q_w%M���b=�K�[����"�H�_63��k@&�����q�����7:�3�2��C���^�0������~��;����U�f�x�%�Z�/� ����ccM"{�h�[���4X9�]
�����]�����x��6	F
>�n��E��NHXtDH����8��*P��-��I�>�76w��o���({�]�Z����O�����N�p���\u����E^u�����R�b��/P�����@@��"���Fs8����`qK�L�b"B�Wz'!z��j6[�!���������tx�~UhN$���d�?U���$
z�ak��i0�����*c����*Fi�&�HF���g�����_�{��3�O(!
����^>�k�c��9������v:�����r�����7��*�46�W��.��SW��a����Ld.�@C�h�l8D�@�/�$�b��=�&�)LJ �&-W}co�Pr���>�&������m�-;�Y�?Y�JU���`��<���h��w x�>�X����
"�g%�?����j`[hC������*��F�g������@cd����z:C���; B�������;.����i����<k~�[���)kK�mC�����|-������fM���������F���
�����*v��Su���W��g"iI�tI%����!�VJ��b,L�Q��' ZNml6P�0� �2���0Pp�N�X�d�Y�w$"��,����1���B��U�����r
�i�Y��ks*����$H�����v������8��!l��5���V��[A��{�RK (������}��t���,h���r��I�2�DTP����Na�pP��)�A"�����Uh�|&F�h>���^��]���P+`�r=�M64c9��1\�����.u������^��d���Rp�y�m��kZ+���o�;���>�i"8��c[�
�;�d���j�P�8�v0��19<�0	6�`j�"��&��0�:z������a`��"�Q5��+6��=����4�����u���R����P����f���R�Q���h=5����Y�SLq�O�����)M��'j����b���J�$�W�8w�;�G������g'Q<Tlvv����M�Sma*��9�Ku���MCL���6��6��� ���+����8��&�}pg���F�l�P��qP�Q�d�P�q�]�8��x���D���za����5kh{Q��^����5f3���\h|�p;��t�j��`�p2�
�qQ������#�lN'���\��Q�F��dN��0�9��"��K���80����a~�\w����D��o�?qF�}��'�/�%�+�?H��N�70�F`�Epf2�)�1���',a����,&��P��/���Y����	�����y[���.y��u3�J`Y�C>��r�ey��K_@@�i���dCJ}���c��z�8��6=���Db;m��R�b5��9&��PQ�
��Pp����;�?��*��-�u�UrQY6�T��Z�%�����q���bt>]��/�~8�?=m�A,<��Yv���P�{g����v�����S�lsL�0Xf�v�T;�bH���Y~H	
���T�����v�������:r��`��� �f/�2|n|�d���8(SL����������P�~i)5KQj'�����q�K���w$����@/F��_D0�>���;P/�.>a���<`����n	Jm�����������:6w��mr�q����l�$���b���E�R�N��� ���r;�
g?�s�f�hn'����{&�[����{���y���&��7��p2��j�@�
�t+�#�W,<�r��������,�����t���R�e�x�����������2#)-r�������M��Ei1;}]��������,�u��������0U���d�r/�},v�� a~�
��� a��.�&�02B��{�@�=A+R/�gs-���/�	��o�������	$�j��R�����I1h�����_N��,Z^�fPh�[�@	e�&��w������&��D��g��3�_!dP�d}�xc)��JF�w��I$q��0�3A��H�YM���a��9%@��~�B9!*d��<������-�>����B��A';HM�)(������q��@��*5���KU��gh�99<�:���1��a��x
o(,?��',	�����xy{7�l�{z���j�xr�Qs����x�Y�;��lZ<Za�����QK����`�~��RZ��\z�mfy���t��y���G���]���,����*NN
U�r��x�����$s~�]D3����W	���\�����<��)�\�N�`����W��Cu�B��7�����]�~=�(��+�0�>p�'�����C���_�T�E�����"�������=�������W�S�k���������.@���%Iw���c�����c�;RUf������� ����!�d��4�����*�$x��}3���B3�m��X�X�&�M����7N5�R����zk(q�/v����6�|.#�4>l13���H�H��2p&�=�4�r�|�'=r���y0��wQ�dU^�F��lZ�`\���.�����'�-�R�u�"����6vm�H&70��}��]��DU����*��d�{������4��Km��9NIV������g����4y<�B�����3�l�P�<��u����I�������'&����������d
iR(4��������(`0�������at��i��C��_:2��}v�=Zu�*���_������l�15R}{}}�"�d�����_�V�2�niDS���3�i��P��;�5?1������^��+���W�[�P�tr�Q��b���d~
q�U��n���)�����_2�(>��F�w=F���[���<��:9�n��w�����W��_M�J]��B���h�_Kc����^/�[g[��b��O5CS���6!��p�<<Eqix
���M����r��n/�Y��xKBlKIp���<��)������E��x���H'r�g�D����;�<���X�[�=���B���5jA(-�#hTcZ`p���OT3/)��v�������l�q@�R���Whw���9w67i$�[�0���3�g&����;{f����H������v�A��CQ����n�������"��D�b��81��9
�����sqBb�����6_L�w�������<����sk[�N��G�������;�b����U��8�5>�����S/���;������lm
�C9�_f����!boC<�/�Y<�xL[|�����K��e.��R��Z�!�� ������q7�J�Y[��w��w
S���d���+R�k�~�A)5�Y�b��0�q �y�RN*s��X	�6�1��w"����f�^B�����dG{�Z_Q;����:������>��8������=6���`MX������fD�#~��$P�yKB5tj����������`�����\n�`����51@L�f(��&��`Q�b��x��������V��DU�gS?��(^�/�^]�5M����W�j�z����cv��6�ybr���(s�f�I�n�t�����W����@:�qr�F?���&���u^�h
�
S���5�� ��Yo��
���q|6�t�W0XJ{AZ�\CuH@~�5�f1��
��wE����X�����������
�BU��������qj(�*�p[A�� lV���'������[����(
������S-�Y��mq���#�*�mI�T�3�k�*���!��uTA~{��4�1a����u��jJh����[3!�2[�b6��n�
�lO*���S���L� ����S�pg#��������\p#�|w���~�&�H�Pd�<T�(�</�/�Q�(el4�j[�c8�L)�yW�k��@�$��~���Rt�'u�+���sI��4�HR/����!��+o)
� MK�����A�hgz$iYf8��P��
p���3/������J�#Hg^W�
;�9��L�����fh���%�e�1�7�#K��������a����w�+A��teiv^_��;�I�_�7I�s;t�O�wI��$���*����5��.����X	���8��b`���W$��g�_��j����N���}W�3���m(:^�����u���r|�xaA�<����� ��{�7�9���.+�`��#��!�������g�+N��1Q"8s��|�m��.�2�L5�������z�"�����(Q�������V��AV5M�2��Di9�sxt�]��t
�!�D�~z^��C%����
n�_����hrK?���7i�2���7~�t`����C��GE����Q&�Fs�e������j}�6B����d�E��;
���F�;��+��7�p��M>�=7t��w�����(��Q�9�����������<:AN���!�e���z2*VGBB����#@��1������Wkd1��Oj��o�q/��E��"������Ig#	�t�2v�`�VL�h�3���L����L�����������@���m07G�z��#�i�$����������5�h����#C#6+�T��#��*!�^y�c���:�a�~�~h1�w������,��[��3A\���z����1Y9+)Y��"j��gk����A�Q1�S�����x5fT5�H�|���x�<�u�AK���q���7�hv[r+�A�jH��)�pf����@�������A`=���L��t��5%��wjFs�(��y�ah��h�/�}h�~�W_�z��f�L3�)���7F��uU�` �d�A�/�������
���0�L��V��L���@t�
�5��P���4��`�qw>5�.Q�ifI;^��h����6>[��F3e����gD}�������V��(���f��v-z,�B�4��� �u�8����9��w��� ���*}������G�I����
�*�i��h�5����=h�qx��a�1L���+#��6.���	E��K/�j#�t$�5�	��"$���S';W�Q��s`��Sd�����������EC��}t��0D�phI��e�����2n4�I�B�;�|_������H�����H��AN�^����xuE�'U:dP�����*������2'/�X��hS?�O8Q���������u�i��l����O^������WR��O +Y�I��g���������>-=��]�nAZ��f����O��u��Y����#�R���� i]"aq�{n�.���,hB�GHi��������E��}w��.��cR�'�=~MT�Ri+����8����"y���������HG�p�F�l0U	
����hY�%]���M� �_!M�c�+�e��R�t��g�����:�Ghp�L&���AoHGE�D=!��C���`4�$��m�fy)���QfCw&���o�u1�/X�Y�>2���	Y(��FnB��(����nM����#y�o<��7�4�)2,���s��;����L���0~��FU�����o��(P2-�@�(�Fq�j�F��6b��E���j!�l�J��v����E(������t�#���
�t<b�jj��s? �yo4���}���1�U�����+U����*�8%���$��|2
�!Cp	N�%L�K�Y��&�1EM��!�8���7���������������,�`��-k�]E"����������C��^u;'����/	�A�6X�$r	T<Udl��J�Be�P�"�GJ��lhS��WURqr����c�������*tC�S��H+#�TuSU�!+�"Dr����������C!�[��,��({�O�p��D��^�E~@xRy
b#��W�����j��j�������D.���D���s��
2�)��B.T>��hem[�GL������s�tX��B��c;��W*�]C�(a`�A�W�����}��r�P���lf�|a�GB���W��H����(%���~��$��.������'g��a)v4�yH)�K,���
��������Za~Z5������1�:+n$U��w�fV ���x�^�d��s�&h
�i��!p����|���a*bo�19�\v�^�&��2��xw�NIq���r�V�j�s�y��"��^f���y"�q<����]��95���Y4������?`��h��3�����@;���5\S�_\���9J���z�N�L .=���0\�d�� �6UP=�Q���\�A��`;@������Sv��j�u�50���*MI�X���9(l/��'�7���^������;>�C
H.�o��P�azN����^lK�mC�����W�&IE^M������������|�,������@���vH(��`�9������`�8M���@��Tx�=�a�L/�����:[��z%+K���9+��m3h%yC���H�U6N1�2ja����#�)��^�	����M��|'�V����F&�q��[��������3�h��2��A��1h?��<^�>��5q"0ze}Q�<1X�U��Z����{<>����Y��M�R��X����o"���M����*�@�*_U�n�~�{��g���V�7�����������;����3�������M	�pj�N}���b�P�-Y���c���nU�X���T��UR���*�CC=�,�B��/3Dw���3;&>p"���v:K�t�QTh��B
6l��Jd�!���z>[M�����&��j�����\Jc�7F�\��k,a�=�j��cC�=K8�PN�Bh�,^�q������S����� �Wil&���}�M7�9iN�z�PH�t}��K��|Z�Y
���d�"t@���]u(�tu�����R��w�����d\�.as77FwU�N��]��]	�p���$��s�&�����0o��b|��E)�)j3��_���P?�&!����p�f����p����)����t����?�)^I�>xi���I���W!�G�NYp�Q�W'��Fn0�W�O�kY�u���E=4�sP�r��������6x&�7�h��Z��D���=y����y�\cA�B��'pN@5�xvG��I�Gx�Hu�+�C�v����1g0�@?�3Y[1�������`bV�Y��[�>�U3��4��wi)m���s���������y\`	������=w*��=����~#=3t������X�����hIP���e���
V����������7sEe�KS�F"<���*��3�$�4��T�������9~�6{�k
�!x/j�'�Z������`�?ME��9��	:R�`�	�A��/���[,���P#v�R�����wO��R��Q�&�|����@���11�@��}�k�&OR�:dhQ����Z&�p�d�-�3[i��R@f��]1:��@�u�R#��������LB��jB�g��q�i{�W_��~�2>�NU�M�t�b���T��h{	��m��D����h�E�W��8� ��7�>���u�&�V(����$����[)t�������G_�B���c���'#O�����* l#���G�,���U�E�m�sND�U�_*=�n��;�y�Q%2�<��o���F����M������{����=�RL%$pj�R�|��\��m��d�e}���?�"2�M��"j8N:D��H_d����"H�b>��o�<G^m<S_$W�K�.���k	��z�Bb(��:B5�j�}0���CS���
�g�X�}q[<�.r���7oB�?�`,E�w��IF@u�o&�sV�wBR�����FW�]��yB����p�F|u�����2���4{�YB������r>�X����W���x<Dzi�t�K�3�\W�Yvl�BUz�^�-Yw�4��:��&���Hp\�����N��>[����b���W�H��'"]���?�UD����]�u�y�x$����B:b�A����E+�FM>���@����Zt�������NK |�O�����M�K���F�ZQASG��F������in���
K>�����X�D�1�9�!���m��x���@5��������C�+i������h�:��Qc���8�
���:�e����1e�DU�9_q�\����
Lo8�2���
��"9��`��7K����B�bjK�}�����i����)l0_�[�H����@�?2\�2x��X&�T��x��G��?��Ra"�:�8���`�}q����]�����u�i��<}Y�F�4�=������:��&��F���+�� i��S��M|o�"��[u���p�ID�j�O�N?Y�����)t=��*C�m��'�������\Q�Z!F��v��`{tL���F�D��h"������4Xn�SPq���y���5���W�R���`[D\�Id�G�"}���+�)��P`�I<%c�Ate�-�G^�$���T�8���I'�WH��e�	���|�n;1��s��YI�4����Z^BUI��p�N��p�
��:\E��{��\J9{��q�>Q�Ro��0��8Q�2+�E�>��\� O$�B�&�*���(O�%��zp��${�p7B��[�mk��L�Q4
���Ux��k���^%�w4�m�����c�$E^[����-j���(����z�� �"��2u���q
���v*���������>����A����vub��Z���]\�R��q���!_�����l�JDf	�1z?eQ�5�P��UFcD�,��f?<��S=@��(�A���A��	cP�M��lG�L�e�d�C|[#����Y�L3#e���6F�!e7�����
�#�D����"�+������ �RN��q� ��{7��.���B���.���o����Z��FG����6K*w�O�V�����K'�F@A,�)d���QSZ�
���k"� �::����!o�+���WW��.j�R�yYBp(�[A7N����a���>����E>�K�F�>��k\j�h���K�o���wu3�xm���!�C1�����05�Ef�����%R�@j�~S��l��W�V��9-��]8�v~b�W�����2����u�_t c������^�8V�Y��%��b��p
�'tx�CQ�����|���[P��Y����/O��6��Qd
��o��5z�{U8���L�%��Ql��YN�m�b�D�&,�I�,X ��K��;�2���!<��JL�-a��%,Ut/w�S���		���)�3VYD8�^��L�|f$��JY��6��8�dh���x>`�����\���Dx����@�cg�����k�j|t����)��B��k�u�x�������"���c@:�s'zR�f�	��H�#���v����Tm�#(y�1�r����t'U�b^TH��gBPH��Lw���R���3/=�(W��#�`�A����L��T��j��U?�AS�����.$�~�h�����]&��~�H�nL=��Q&�N�M=]�\)e�(��}C�2 ������8�2��9~f���7���0Q7���):��w��3�=6��Qt�'&
=X��!�+�2h�����VR�M�RvY��Cx��QF���;���#���u$����p�(�8!S!+�
%�~���G#�9E�	?���x��� ��5�bAm,���kj��S4y��c�&b|
1����`�mAr�!?gs>�k��	�����f��	Fs�Zo�i��.�k^('�1)�$t$�N:Nf�j8�}M���)�������V]8�I�����e����['ga�C�&��}���!�.��>�f��Y~R�#~�������z���"���F:u����o����>>K
��M�����u5m�!$E4���������3�Z��Yh��k"�rMfn��H�:�.���|��GxH�(��${����[Il��B�m��%�d<��S��*��nf�[}/��)}L��#81�|-cm���m����	�k�c�,��sw��|.*M�M��Z�����R.��P�p�	a�%FK���D��
db]��k��0���#��S��f�8���j4��r3�#q<���K��@����Eto�-'�q�ZC�-W��m�,0M������w�M�=Q�ve:�G6��vFw��T��$F�G��5����}�S�p���K.���.k��+]����C�;U�9\��F�2M������d].�SXS,�c�.��* �����������c��9y)�qu=����9�\���}sU�0����r'���\N?P�������'����j���������?
�;�)��	,��lu����	���a� ��*49)�<���Z�Qr#��<�Mu�)W��K|��=�\�9s�`R;�.��*b���5���L�,rRU/��/v�����?����P�9��/'�s)���f����1��������X��4��"�N�z�	v��C��������]�	���A&/����b��Z0p;��-���+�I�t�C;
���\��Uz$,V�~�Hw��5�w��0�G
2�x�ad��+h#xwl��5N�I����nU�x���9=i�:��*�'o�[��<��P8����B������s*����%�4��o00IG�_�b]�F�� vKiI��]��i���
�A�����r�����.��O�HHP{	�N����r0t���WD��J�0C/���
WK�3��-��K`L��i�:f>������
���x��SYO�7�t��q+rYe�4��0�-�.������&a�b�����/UR�Syo�~��f���W4��
AU���b����pI�n��`*7���:�j�� ?�fH�b
`�����������kIS�r��
�~�E�+��-�I~h�����h5d#X�e23>���������"�g�W�E�X&A�"6V��f�uG�5P��Qt�*�����B��Y�����-?�N��"zM���[�(*������}��Y�����	o�&�mL����������i��8�ewKbk6��rV�s)i�T�x��:���[�\H�*'u8<�E
�Q��P����a,
���)��}�OG��sr���O��?�����q�2S�������}N�������|�'��C�}1����ab/�����n� )�4L��%�H{2Z3Bc�
��������99��3zlF�����}��Z���0�J��Mn���hP�:����&�Mj:�gV�!��SofU���d��q�U���fSt�UT�~u]sRwV�����Y�=I
�;dD`�G���>����r��M����k�N�XY�s���/H���eZ`=\pEh����Mer�=/v'�u�(]}c�a���"Ba�Ul�:��mF!LP+EE����E6�e���)���9e�X��!)T�^5�f�����V�����d�ye�~�e���M�Zk��D��vS������I�2\���/K����s�`_W�1�f��Sx��;/������m�4���������.����g��I:k=�t9�^�Ye�/�=~��\���r����<��(5��������q��X���/!
��_�qol�`��i����0�wU<iy#�4�v�T]��L�`�j��!h(�Q3�*~��%�0"�*>�+�t��������9U
�K���1�������gy=�g�>����3�nf���q�5!w:X��8=	�~q]����qq��t�m�!Rgg�R�������M�������H�F���J�����M��O�\�s���R��#� *hS�&�b�zg�{{95E�G���NL�N����Xa"����~D�0G�
"AP>:�W�yz��JYAM���%D�L���*'������j,�����T����4��4W�75�������	T���B~��s�R]v��),o~����A���C���6���.��V`���I��<��_����d�!:�ir!���1"��5��T����(�LS�^P����0� �-$=�l��Z$%0�.$����S��#J"���C�)(���|q������l�Q.�}�Ao|,p�_d}�TR���)�l4���`O_sCZ{�:}���D.}^
'���Tjv���8d	�X�3��|��n��A\7g�.��T�����n�`�h�laz������?�J�M��NP532�\���?���,��J���b�o�����Z6�Y${[v��E�X���cq�i����Z�h.�>���3�1H����
�\��w�5j��b���)������?����K��I�B�!%��-�0I�����B��q)��s��'C�;��G��#�d<Mf�����C<>�c�>X��6���u�&���h'���w���������NT__���|���Z��G+++�z���V�����mG+����g�F7������ ]��7fb��3Y�{B�\�J�N�����V��������J�����c/d��Q�*���(�IM��-K����X��M���	I���i�5�J�j����G�y*���zC�R���������?��6p�M�jB;����G�d>�Fd���F�����V*��%����kA���������x�L���F�[�T#���o%�U�$�G�-i�Y���qI�6�%e3C�vw���Nmm{w#���rDlVH�f�pm�#�R{@��
T���q�k���6�.����u-z���+~
��TU�`��G�e�DM���N���b������%*|���^��U��Jvl��?�����y��V�K@k4���m��3�����U�9�=Z@�K�Q�4���C��}rv�:V�i�
D�]
&�=��Ev��(
j��q-5�\�m����� �������u���N��~���H|J1�"Z�0@��P7��#��k�;�f>'O{��S��K���Z�����x}{kmm�|g{s{/{�e����Y5�6�6j;
�E�g4�o��|�z}�������,�� ��|4I���W��h��+~!zb_'����8X�FS�2�"Nko���U�o�F��U�
,���v�qw
<#������)���I};:� v`r��9�B��@$u����cov���0�*hBA��l����3����������q�{����_���E������p;P%�L�nv�j7����A}��n�f�7W�Si��[����_�m���3s���t�kR�QW�Y<�v����t���Y�Z��T
�="*����YnsWc�����zMb,#����_���s ^���>���1=W�y��W��Gj��NI��/Q����X�mD+���-�!����|�8���&�zw��u6��b�sr���YW
c�\~��$�vA&��V�N��j�=Z;E�dw�.����1]�!
)�zr�����@��yu�P�����1s>�����B���$��X��_�
�@��|������^��Q���I�)�Rdcv�����Zx�N�]\(�0��M"V�������F��
��$�)��?�Hn�����6zCE������V��V����(Q���\�5wh$m���(fe0��O������������q��WG��I���~k����y<K�tU;P��@��'�%�����:�+f|��������A.&s,�h)0�)�o��t)-�|�=Q�jHDXq|��]ca�n����I�L.7����|mm#���7rt��%WA	����[_G~VG���d~���g�<�{H�����\z<l�l@��t���x��9*�z>��9�w=���G��_�^�B��^�1�M�Sk�G+�@n�=���2������>Kb�������J��,�b:���/��?��(��]tau������2z��[�}Q��������86�RH,
'�j|5b�x�h)���
��eorA�9��g8�'���G��������2�D
9�	�C��_Ru���QMM�G@R�b�(lXkr>=Tx%F��3���7�����0��1�&�����w5�u��QG�B��j`�=x�s�|4���xz��tR����/
3���i�2����h����.���'�ly*�]�L�Oq4
'_���?���mp4T#�c�f�>XB���G�R%��� 
��m�{�=.j�g�)��p4�O�����>>�x6��MoY�Q�Y<%���P>���y��w��]��x��3��!�A�W(��[���i�a�
�X�q;��*�_��'{t<�����F��p���y�G�84��*��p7v ���`
DSL����w4F��|8�=�J8��[��8��y>qpJ�4q��Y��]��L������i�A����)����A�mg�&������?5��.e�����Re"?7o�S�M	I�x�����3��pD���O�
&���T,�e>�������E+��$��6):�pdN�J�	P
(�tE_&�[B_��WV��HH)P�<V���J�!�%:����W44,�B�rg��U�6��2����v����K-���	-�a�r����S�qp��p-<��I�%��,{fQz v���\�����
�������n7��x�1$�B�y4�'���(j�����#BL�t.�T���,>���Sj���i&P�
$,�{�5b��>Z�����X�(����F	��fms@5�~2�y=S�� %���-�Agps�@�^-��TI�4JP@tQT��Ur��x&��<j������l$Wx^a��E\������}	t�L^��)�g���n0!�
@l��FWW7�����~a��%�l�����0��*z,������/�Tr��Y�1|y&/m�!�&0`���W��������o ��L���D-��G&g��������J7x>������[
��>6WK�?08�8��.b�@k{zv����~�u^o�b4U�~�EO� -���R�����RC"YHA6����������o�p��X������fG��R�}SY��\����:�����r>�]���|��^]M�� �2O�,r{D4��j�w���i��Xx7���*{_Ej�9�jU��RA#D�WDC�t����c�> zk����\����9"����(��`:���D�$�oO�b�>\��Y%;�5_4�
��-��T���3�����!�d�������J����2�L�C~@\�����
>t�Ub���������
�������x�'��N��B�g���[������7�E���U}!�����b�C��V��J��-��N�Y�B�� �E/�:YO���_��,�C� I,]_�������)��bR)x�)Y�4��7�L}�T2Jr
W�#-{�@�x$s �����(.(a�j��z���e�D(�
4����o���v��QQes�I6v������[�a��� [S�Z �#��f���>�����zOf�s`0�4�����
M[������|4m��9�w��kuEt�66j�F�Y(|�p�����;���t������;^���Sq'i�@PFU�L�o�����h��Q0}�y��"	����*���2^/��L�V#�ZS�KK8�o"}��$]*�`C�/���I���}#^���o&�
dMT�W#n'a�����bJ�x����e?������^����X]���'�;��@����D���eZjSm�^��i�%����r�~�E���o��>#�f�'^��^�@/�������6�dpu-;��7k~��Vem6V�m2RGH��dNiCly4�UG��v���A�HI/�1M�*�J�y��z������V?��T_���.�JKn*���W�T�S5�pc�pd�
�g��b�1�r�J4�'�>�b�
Z�h�C�9��E�FC�@���n���&����C����������Y3�+��x[]��8�a�pqz[��^���H���3�q��qt�r���ov����ge���f��
,<R����<r�D���-���H�:�
��(A#��7ST���_������X\��_���=�����X����X�X}����U�CyK���u�/7n���_���46<2ah�QA����0�&{��&Rl���s3+U��E�������
�`	X�������#�L�7,���+W����<n���3�L �>���5���y�ej;���^��6i=�G�����������P��T�]c���Ih�to;]P�O�X$�?�.H�V��0�W5�zQE��������4��j���Mr-,���	�����_A~n�o09�.��I!o/
���{d	��v��'����������l�.��7Q
	_��������I�s��tQ;:�aq5%�j�����,L��q/�"�����9���uR�.�z�z	(4������[����q.�'�:�~��u��o�j���S�Mh��QCO��0�(i�1Z�P"U������j�T[�@jqW1�6=�%�
tf
�So�S��[9%�$��J|��cMz��]<J!}�����Rg^�.��?�M���������`�����xt5C{0���y�-f�+&{x���5nt��M���h�k@��X�-Z�q8v�V�58�;�^�|�C1bg��J�����7���6��@��M������� C7��]c�A�tY&7�nI�yC�<<�����dG�����H[!	!�3kL5Q,X�.�-D����c����4:�����6g�J���
X9��z���/U'�����F�B	�.U{ {d����6���^�i�6�?}����J)-��T��2��r��y�U��"J��k;lJZ[j�l���y|	`K}q���
r��/y
!y��|����>n�m�Ag���~�S���*�Ij�[�	g���uF��Q�'���"k�����z6�,QV��|:��&u��E��5��g��G0�n�E����-dNCBv&W���7��<W$P�j!W}�B������&?T��ror�\�W������.UI#Z�a�nj�sy�#pi	�=A�b��������vL.�~�W	�$q�-lVY��P'	<Ay�@�	Z6�.����(8��hK����d!O	������AP�����bFb6���/�	h�	F�c[����0��jh��5�mH��5j��}����o�6�T+<������/@�(p��W�6�������)2��1L�HAz�y4R"Q_W�d�l	J�G!IZ�AjC�p�k�#WA�0'^Z���l~����!F
9���l2D�]����-$��e��R��-O>p�����X�D|�@� U'�'h��n�.�Gan8[�]u�`C�
�)��"\�4����y)2/]*\�,����$J.�7��@�`Eg��\
�>�&�6z:�&�z1~�XZ��j�Z)m���'Sew�2U��,���p�g�I4
�mQ�*W�*��2��Y�ZP���+�g��(�fV�"���K��Zc������?�����A�c���"6�,,���e�"�6�������C�j7�ZJ�3+��*����a���-��p��Np8+A�Q�|2�)e���2�;��oUY_W;r������~w2�	������j'7��8y�W[�����|<9��������7�������G(�e/kZ�����.�}*��Q_��"��9���Y�~�`�9B�Z�rkQ����8�"���������� �(�����?�$	S���$�"���d��c$}~l������	�_�d���Sn���sW�aW2��Mo0�V������&�m���+����M������K��]R��vD������Jv���)�v�����p�x�����w�\j�!����������{�M�T�i�4B4f�exeE�$�iy�����w�����7��~�R�����Ufb�xu=����)Q��Q��K/H���b�q~%V�_�~��	�G��f<�Y���Q���K�0r����<A	wiW��3N7j�
�\������r4��J%��6�|.<2�bf����L(bdS�z@��h��Fv��a|���#�S����q���Dh���K�����`���"^�-�P����U��}:h����&�m���ldtP�B��1��QS1���wd���A��^#���[b���-0Hc8e=R})/y�_K�+�����j�S�S���w�� *�������P��1�
��0x��c��Z��o�c)��a>���9�����f�m�2;x���X�D�
����'�;�4gd����s6����D��!�1f����[�Vj�����j��J�x�:��*�A�
���{5Z}��m,���P�l��B`1��8q������t�D�d!3�����w 
+R��Os�u���$�Sv��>^��A�`���.�Zs�4�����,�8XubL'X�$�d�
g_k�����n61����^Y����%v�Z��"��/(Z��qD���!��y�vd=�������w;'�5��i+w��
q�/�q������x����6���w7e���KD���0wdk��Qqeh7�n~s����z���5���wu�pwwi3��@���&iZ�~���	D6�}'����M���@�bX�zIPc�G����L0�;�/��� p
^�a���a��	��'nL��;E����:���� {y�d/	A���1�^zA�J�b��g�������F	�l^w��T@�@���-�W0�����^��������t����8{Y&�Y�
r������xg�����ay��*����%����������c�&c��q�"��
y��'��t�(���{A*��t&r�N~J];�����$���6��yoXe����ku�-�5�"��&H�h!����@���5]�A�EX_b���B2nx)-�5E�R?2�G5�CB&��/InG�C�X�
9�/s,�]2���K����c����������+�������wOX_=Gi�y'
��@Wyq����2@��_G����\
n���Q���Bt{��Cy�)Ni0V�>���}*�*>���Ec���������rHOQ\���I�:rG��VD�W`�'i��T�j\��	��xL�lt���2�y�9|�� �p�����4�pb�?��t�������H��KQ�l�@��(RF�K�t��Y��5I�(S�b�������Qf��_�^�B�{w�h�M����MV�A�X"V�?k'���Irs
�\�Y������c�+T��p����M{'j�`��f���7H<�a���N�|C���:���i��8>:�;��7��X�bd(�k�j����#�f����D���S�&��G�B�CQ�����g~O�*�/�!?)Gw$���9���ctf��k����lH��V�PH�;A4�d�Y/��I��@g��kc��F�%�=g��,c���x�.�_8�T�����/3��z[�W�we|E��YZ���p��&��n�{�x���	���TG(�p$5�7�#��$���ff��F�q���9��2���:����R�8%^t�x����Z���W)�t}�Mri9��c]j����y�}�|�����!]�ITkn������[8���qu�^',~��#��'HbK������X������5���J�^Q�E�� S�z}��U���#���n��y� 4��s����3�������������C�������f�M��Kl�1����3����]Saa�%��f�����1��"���
���
x��0h�����/�����[�qc_>h���9�ev�X�����c������&�#��;!d����Ab�o��0����vm#�6j����e��t,��`��)[*���(�]V�CR��@��"�f����r�?������^F�YD.`uLN�at��`}wv�J���rk~[���;��A���g.,�;�j���+v���3
"T���{�k\-���h�����M�.c���3H*�vQ�aYt��w_��4}u�vF����8���:;�K�a�7W7����f�����{~�;>u��#��Q_h?�����>�Gw<1��?g��)S����?�������^M��^mc�v{�E�@/����"\9��SS��WS�!��2�������x0=/�G�d�`i`�������'�uU
�������?�?��;�����$�?�F�(���Ft"�>��B1I3�8�����W-�tCN�9��I�n��#��7������EJ_�j�w
���l����Q�0�=w�q��������������?J?�����1������\D+���T[��Z����^V�p>���E��5���o�/���H����Yl�M�ClLR
�-���oY����GK���^�<t:4F6�����n(�	h�6N�I+[��Hn"{���:��6��`�C�'n�E���N��Y@E�@D��L�
P������0H�Pu������D�����������Vw6v|�.�D�E�vhj*?a�(�5�s���Q�C!J�t.��;�;v�+��m�����N �-}���N����"m�/�6��]��� �;j{����d�Z�%�>��w:���~N�$G���~�@�|#W���o��P���n���	"�����D����L�Z���E�p��J?��n�����'�(A����o�=�rP���'�b%���	���X}wGQ�����g���.�}�]SIq�?j��Tp���L~\c,V�������� ���>.���b^h^��
M��`��R�#�>s���2����S��Xx��m�[��L�w��9�����-3��h�N��
��e���74����!{��?�)-s������Vm#Zi4[�mq������n�}���P@2D��B��ZRN���z~�:I6�$"����7�q���V���!?E���/�%����cd
{[��"��n�������Y�S���R��h���}�
�Qe�p��'���������{�Y\<9����M�c<�[��^t��	���������C�d�N��@V���|���y�g��������N��������*��(x]~�<j���V&���t.Ofh\��I��Ui�s
k:���ikhZ�<a?/�m�Z~�d�]�Y���h�;�bD4\�k��< �vu:Cv���fj���V���$8�I�A�E~�*�'�����3\&.���������@����}�}��l���}J�bBa|~���pp���T�y5�����R��e��������+��� �������o�nl���=�u3�n��"����������p�������xA�p����+{n6�����k�"# �E����#tz��Z��# `�C�����O�����-��tW�'D%���"���b�Q���<eK.��$,�E�N�R	�/���t���#��6!
��H��;�4k�1g����Y:R�#T�V�:���n�j.�P��.�I�f,���.����S������8u��!���u�

$�A�Oo�t��6(�;{�a��^�N��]��� �&I*|�WG��N�Q��h��|�j�4��E���pU��c��H<� �����v�M�M�_nz�����(t
uB�4�<3k������V�N$R�����t��%�q�BR�m���v�� J�zXz�
�~I ����z�Y�6�J��tu2��h�2�O��v.|�
��x�\�������X
�$�kD��y���ww��
��Y!�5&���0�����HNeV�rl7hx5����^;\}L�h����o1��b�#
4,!v9�w�H�(`����Og��$\����_	r�VDU�Y����~e�T���f~2��:��W�X���AU���\�9����fog���������c��V�A]�{x+���y1��+�w��>Y��r
��q0��a������%��;�������W_��Mz�[X��`I�gv+!��}P�{?�]X�����W�\�������������6Z�C���t���$Qro��_���K�FpL:�P��A
��9��qG�G(���>i}0$Q}}N{��Zw�d���bdT0�k��0��M�5���b�	f�1��(��zH�
���TJa~@a3�s�M�8��@��W���b�7��j:��7�c����P��f6��0W4�yAI�_z�|���������z����(A$�1���
���uh)�������u�>�����H5���g*+�E
-�F���K?����;���iEZ+2�q}����p*R6��'w�:��D�2��z��|II�-v�X"��	��$���2������;S����0�lUI���D�kPk��F}>j\U�����2�H��~�
�� T��&�wU�PL���eg��PQ���	}��)�G<�V����[\s#Z��	�zM�?�y)B�m!����}I��f���*�9�3�M�GJb����v4��r�j����ll��zks{���["R�OgW�+���$n���������c���h1�jT�N�L
���0����j��9�l�E2��OPE�h�*z�M�IG7�(�����!F�����Z��&@���Uy���e�FU�y;�5
?���;���^Y��)�������!e����M"X�P^���^�&^|����������[4B��7�$��Th����#$���:�����Ukls��kE���k����ltM"��zU�P/�v�}x�?�Okl�-|��U�
�4��7�3D(A�4{�5�X�����!���(���b�P�@�t�����t�)i����|�L?��0,$>4q�q3����P;~�}C��?k~�A�5d|��!���7�Ws�@�
������7�e�Co��U�"0��U�	���(!^�co4	ES��`��������H���
�z��$��	�bxf:�;��h����zjl���_��5VC��\�a�9�
��0)�x4�oug.�] =Wsg���>!�SkP���B������������1 %y�:��y��3��sU���}�����+����sh���.���^7��|n6��ltq9x�d"4���l*���jV�)���haQO*5+mN��������2Di�����"����k���Q>�3:�7�S��f �(D�������eL��m�1��������v�$��go�����f�����-�^���}��3�4|s����9�����xP?n�y�YO���/����fkuMc4h�gH����Ln��`A;!�5��������:�%���b8z��d��-�"�4��(��l2����HI1��5�rdD?����p0�Er����~���*C�%�?s�B|��S�Z�-94�?��z�vr��#�3�0�]a_N��t;.��[�_�msN��;�	7+��G��y���:Z�'�!P��8���,�>�v�JC��G��i�=h��?���&��Q�M4�U�����#�^o��v���F��� �%|\s����qM?#�:k����J�����i�����2x�*�cal�*����/���$��;���~�������*�������{�F���N�D�"D����d����X�C�������x[�p���1���hy�
!vC�C��3([ ��p��"�b��������
�d�-
���8/��(�HA}*�O-]'Up@��i�0�X�������C�q
���`>k���?:�|{v����&F���[	(Tf�vTR�V�q����I�����f2L��'�^�����t��5������6[J|u=f�|}�������v&��>��{#	��
���H�����v#�P�G��	�E3�8��$|����u��3S��i�%%O�WtC�K0Gz�qtx�m�'���jp^A����d���1F\��o!����� ��>�g�E������^�������(�Qk.!��t����]I�7�.q�������}"+��p��r���3�>�g��R|�z'���<�	g�uI�eC�<����M�g���a�}
�����=��{g���t����h�������b�(W1Z�$Afr�y�xx�KDbB>�+���B�z��'�����lT���1	��BYE0�&�%_L��"['��"}\A^��e-��j��o-�J�����<�i��pM7��lt}�{�"��q��V*�����X}q��
2���t��m�h�G2%��-c)<xWW�zA[�
C��V���^����Nt�_�A�+
�����������6����������2��.��w�1|lg$`y���������34�W�������D����X����:T�B��f��g��la��qO���4��1r�A��<9��qU>�;,�`�A6 ��p7U=���PB�
F��c����&������f�0�'RB��=^��j��T�*�����=�K�El�����l4�����+Yx#c���h&�`[Y�S�
�c�!����r�@����K���,����O��\���:EI��+����TO�x`���+�>S�����U��_
m�B��2����3�\%��uI�#��SZ��{Gl��N������I�."
���lb���O�.><X�J`_��g7���^��{�H�F�����d	� [�B��y7���X�xd�&�It�U�9#4�c�+R~���(��J�����Fh������	R��}z-Q�#�~�N�L�-�I����Qt������4�Q�*�<�1�+R���������>�
w�&~
2~o��e>\A)e�������bD���Y�z^���x9�3b�����a�{�,_QC�\h�O1��f�����Y�����f��z�=89}W���:UrmC<ll`.������:��P$���`||����KB2���s���@���0��g�&����wO�����B�����@�.��_����P���{�����9�@�>*�nU�sl�����f��hy!��fh
���`
�M0����-�����f�k �IkB&��Wc��o�gm����j��:qK�?B
���7����)�lNC�*i^���n�j�lm���J�E��3#uTkQ
[T�(�|��q1o�d�c_%�IH�n�� Q��e�J���Va����U���s��V��sY��fe*��gu���v����_M��I7i^au
���^���!������G@=3� :B��z��%A��PC�1��!J�$�%���*D�E�,��
�{�(TX�����e���.���	��&Z���P�����h�J���uI�\No�C�o�!���=G����}6=�L��{F>t��yG���V�h��(�+"X��FuUR�G��.&�Y�F���7�&&����7.��[�O�h���?0~�B��p(�<|8�)N���C�y���=��v������d�
�B�.��*o���6~�y����f��4Q
\M����T�u],6\��_��h�,����LS_��c#)������r���;$K�K�dl��Z$������������1���n��s&�E�V���~ ��k�`�o��7�)���t^�F!�:�����
���,����V�8}��^^Bm�H|��Z�����������~�RsW���U}<v#<"�2���,9m8���A3�S;
3NI
�c����������6_���:�@��y���sNk����WE���xlh�������}���s���$fX��K&�U�<Z������[	/���"V���M�^������X�hY���5���<�W1)���[5p��_\��X1�xh����[�q��/�n��W���#����u�i������)>K��"��z�NODzC?w�Nbi�����G(15\e�=m�6���
�_v_���U��5l)�	����|�����#c�EX�uZ�#uZ]�:��m6������hg������r�~a
��v��"���)�hZ�=��\�m��_��\�&\!%P2������7un��������561���"/hC)�A�.\��:�
En2����v�m��} Y�2������}h�j|-S��-P�����]_$���Nx��Y�3a��r7�\���}������nH�K;����Os5�M5=q`y�&|��~�}�=2��V��!-oC6_b��5������'1UR�C�4O3�F�	qn��['�a�!���
�Lp��fp�6�>���+�@��E�r
�a��*6
)��Q�Z
�� @��	X�����mE^��u����Y��=9>zgYJ<$4H[����j4�8��[hq�	�����r�D���NIO����h4d��
�s_�:;usLM��U�DXL900�Q����7z������a�~�G�M
��3^�Y�P�����}\g���t!��	o�������VH��	���!��*�}G��H>�l�(��#!qNn�<��n�@���a]��'Mcl?5WJzsr��v��?V���m����C�:�7)���S&t�������w�7�a-����(�l��>H���1��k�/��.��,C��Z�o���OO�g�`����)�kc���=�Q���~��=xC�_��vc�]Ez���
��J0b�>$����q�:$�yP�$��Y9�_���?����?�������T�.G�W��7
~%@��u������H����S�KP�������Td��N�b��>=������{���rM��!�����������������������DBN!���=e�a���m}���k��5Q' ��0!�dh���D�qA���64�NpP������5r�5�������T��U�q�p�!�����"L��T�|4�^��=6��M��u`z��,&u���q�Q��P�m�F�D��~2;��oG�%;��oG�e:zut��9a��R����7/��P��N����
|�v���YBk�����nOm�����������1>��\{�g��{��j#o���lM+�>���m� ���>s*)�C����j��<i�����SK���arm�8X:V�S�dl^�G�	>��8�c�a�"����p���l$���$�6��H�
C�w7���4��/��](��^�Q�Bx�;�v�����ts�������d�3���3d�9!��[T�U��t���<J���L���Z�Z7<S|N��z�N��n�)������K6����,-���htA��������S��iv3��W������K���y�[[�76�z�Tt\�J�����Y�1K��b���]]�C��vq3>�L��lp��(|k��&�1Xz����Kg�����&f����O,������i<���5��_0KB-����D�u�0����p;0�����B#�P��J��:���&��*���N��� �N��g:�tV�nB�'�M�������GW�z���`:�LK�v����$��}�����Qr�X�����
��t<Fo����7�@�.f���wq�F���7�5?�Gh@�M<�| �h����E��i�p�w1�������z����"�c��.��b�1(��#����gR[D��������6�����U��i�LU��E����eh�
>����w����EA|��P'�bD"8�W=�4�h|5�*���b4��D�}��h��f�[�ut���m�a:NV��.�P4���������y�vs����|:����)�xby Sei
����5;�wp�5�+��WZ0@�T����}�]cR��W�O�W��:t���mO�=e��� :��7����(O.{3=���4_W��m��]��;��-�(i�,aT�����&S��Y<�����Uc��x��'v�������	���LgEa�l�<�@`���*����?�����R�������S�!�����k:q2��}I����Beu��C3m%���&��0�N��"NM'A
�4��.Mv�� ������{�q'�D(Q�@}���.Z�'@� �����B�(�a	��cNi*������Ap���d���M�,|�-?��/W�[�`�!Z����2��V������&;��#�����'<Iw@�����>5f�����vR{��*����2�r�7�O1q(�����j���#t(�EV1�)=�o�Q���h��6� o�3��=NVsQ�HT7]���=���J����1<�l)��Rr���!N�B����W��#�Q3((Ta�}��7�"��+
�|����#��$ g�R�CL��bM�ZF�9����Q	����'��:B7���D�+l�y| GL�g�����TH���i�m�U}�#���R���������o���O����R�S����_GM�k�n�
�4�eP���r�K9��,aLk��'�����w�@�n���$H��W��nA����bE
���K��4����En����4��gK���
y��UxNl�!^���+B�T�:f>(��<����'� �-�����8x�d������#]_����~\(aD���K`Yu���%���
e�)�_B����,N���3�Euj@�\�������=l���~�m��|o�/���������N����m������������O~8v^�0i����U�3�5�U�l�G�S1��'��h$���o8k����N�0�1�q�����{F�=^��\:�J\��~�f�L'�x��v�����s^���}��q5����,RT��r�x	����&H'��a�J�T�K���5��������1o��jw�k��T�Y�L/8�\���(�!4�4�a�VW_L�aZ������������k�r��Z��a��d���N���W�9)�����iu���=�4���E���W��l}a���c�/T���	�n�����D��������~��������O ����*�l��:P�����M�:��{J���<.]()o�&�Z�l�L��	���Gt(
[��������B.��<��%}`K����!'`��e)���i^C����kx�eJS_5,���Q�|Z�VZ1Z[a4�1wW4	5����N�e���C�w�'�����"z,��v;�N�l�dB�����Z��I'h���^�}�k�4��0/�>3I���C��)5'�O[~|v���}�|�k�08Y���&�$��p�����m��DF!|s���"����\T�M#+�@�X�\�t�.�6�����0gr��x��q_G�K.h0��.U��V�e���K�R���w��{9Hj:�������s��):�o�A�Ss�x���F��<%ys�A��%	����9��s�LK��7g��s���qh����E�
�Ue���1�2�~��9|�����R��
�Ujt;��.+�\<G�NJ�H#�#��w���l�U������D�b:�H�S�wPb�V��T�^��nz�\�S�������u�c7�t����C��x���K������h����������o.�,�~�^���I�xQ��������n�.$���<3��6q �D7��k�5����Z}���V+��*zR$�F�cT����8,L�����&��m(^}��'�d�U����R��8�(9��&,����uX�t	���v��*TZi��q��2p���j%CI
� 1b�V~SY|2]��i)NLmu���}��A���k���j�QQ�f[����]�4�k�Ff�7'G�Z�D�X��uqe�������v�J����992M�~�L���.-�]�����E����r����d����D#����Q�����MI�&�0���+�	Y%��6�6�F��i�F�du6n�_�F{��t��*��m
i�������g�N����}3��� �k�o�������e(u�=��Qi��{H�����N����k��`dp�����]�\J�T=:�K���������de��1�0�%f]T6��F'H1�WY��	$�s]�T�^������t��U�H��>��guC0����lt1���������@�D�3Z���y:7k�"�,�O
�UpDK'�! �����h��7�?b���mp->VYR�Q3��*C� K?�"$�AZ��{5�E=�F����'}��>��G7�h����@{%��a�sS���������75�y����E�!���`Dd�K�V�'�%C)6�|�&"�3���aY�}�h���hr++c���S��]��8�L����E�-7�Gdz�E�%�*^��r��2�(����a�n���XC!���9ug2���z����x@�V��VsH5��d��(0�������p��p�<���l��rO �y�����"9�!�y�_�#�P���cun���\��r���]����������Y�Pq2����e����� ��g�,�y8�WjS���|�6p���T����I0,����l"M�:����a�A�=�}T�at��OH_��aL�J�a)|������,?[89���cH*�
a�nn���+&��u�mc}���`�������&�{;������C���&�E��0ug����O���
F���t7���Q�yU~�V��h�L��S�����w�+�J�)�\M�
`���&�)��s)����R��
��x�]�MDh����Q��z-#��U���5�:���C�>6��g��I���������qW[��5Ul\&i������1���
���cxg��1>P��;;���L#Y����c8vSDD���'4�6j1��ZS�l�������`���*��'�(�Z��
!lx8�4$
>��n�t�K_��%���*�����]�0F��^$�-62Oh-�����jH�l�z�y����k���1:x|����od����:�\�I]D%����/���?G_(��x6]5���w�c`��A��A%T�OP���`fI��&�)%�[�D�I")K1�H-�����a�Q���*�U��=!;ex���*��A"w-3X$[�d����������X��1���G�A�������~(�e�Mn'���)�����V��rp���4B��	�=����Hn0���X�[�����U�#K���@������Y�p����J_`Um`S���rz�T���7Z�:t=P��Q�
��>���`����7��
�w:����XHet���#��C�W�B����B��a���|;}��p]��
���b�<�EI�����@��s6t�\`�#u+e�ht9�}t3���-p����������u�����N��� ���(`$�p�	[��%�;[;{q����{�;��������
������R�;�{�(z(+�D3'����(�E0��E��qF�	U�LtX��u���z�
+��m*�����\�?��m�(��j��������\�o&	REE?����Qv��f#����������snx����fj�C�^:�����;��|"|`x��!Q���H��������F�68���b,vs	�����,���IS=B�z����QC�r��-k@����>�hBg�f���9��tON�v��=8j5�;5��a��tz]Yn��DI��yt:M��:*x����J�K�$C�U`�{p|O����	u�t�S��@b��@	�pI��Q]3��AN[5��^�/`e��{G����A|�Fx�F1|���
6�����|DY��gYTrr�|f�q�(C��iu���u���H6�
���w�6�{{�kkq��{�hcF���2�tK��
L?�t���t����f�z�����V1��|��$P��<�.'��fz~���^TL��>���,G�g�A����	���:���
��p�p83����"m
��{��������a7�H�
��)���kn�V�sc��(�-��4�7/��5{�5�O��L��.?�2�����+�C�]��::���������e0�U�Y��h�� +(�B1lD�{�H�CV\y�c��B�}�Q��,1��+��`��`�7����G�������~)�������_daP&E������?������% �%Z�u�E-�{�_�2����N��pt���\�^��������u
���@���8���nk��-��Wi�X��jex���t����������C�^n����q)�������Z���nno���b
;SU�� 7��������S��7�����1����_�NQd�m�P3	���U��n}g�k��%��yA���]���008aUK�{���^	��Se=����f��q��g-��pS�s��L[���;���^`��;x�����9�H-�m��R�R���C������6���:�%M�o��|����}�&���s��DW
'� ��z��rn����X�/On��0�	�'��[wAh�s��{,�b�P��a�����3g�x�Jd��O�(���h�^|)uvy�,J|D�b\�����Z}/��rd�2�;�'�R��Sj7���L'�h *��^$�,����� 6O���vf���"�jH�����j0���	��L�������J�5�Y���s�G�f4��S�����
�!�'� K�b������
L��66��u���0������~>��[O����ae��V���G��v���/xZ����	P���S��.o�S��uz�����}$��F9	����h�q3g����<3�������
��������_(��F����4������X���Z,i
�������"p7�$xh������ ���+�rg[YQ����mb�6���F6�uG�$e��4���q��B@"��<i0x������dzv����iR^8����2�$N2�����_v��ee�/���~
���������Hz�?@���x�E$%����#�]z������s�������������/"Cm�/"C��r6�n6�%d���>�f�@�<�A���{�_8�7c��-;��E(����s�=���o�jeG�s��g�y{�0�98`��$:��sr:�^���5����2�D�$��a�����v� 	�����kA���^�>�a��l\��q+�3�=���^�!����I1
L��hl�/2��0>'�Y=���G�R�yr�}}v���u��|5�������������G�h����������9{1ZL�s*6<=�qs�2���C4ag?0|i����j�u�0L|�'�{��M��
9��R�'7��@�a2}.%�|z���K��0�q��0)
N���P��QP"�$b��&)�Hwj/r�FYA@tJ}��-�s������}�if��{1����<ykNo����d�������9N����0TH�������N����B�����HF��e<~�����Z�Gj
�g����,�Y7�u+@v����.f�:�&�Bd4���n� ���N�DK����������"�^��IV��f�
����k[���UC��ig��N��f`���~^T?!C�v�9&�	�����;���2ngT^�t�"12|��[��r��}��z��U�]�G�SC�:��@��6 ��i�|r��(qz;&���������Y�;|
=>��&��6����%�L�
�,���%,O��&��u�&������-��n�m s�xw��KU�T*�nU����5q�#y����q��Zm��H�_]�~���G�$�����[ ���PZF�;I7��X����\�b�Ymu07�y
tc��*��p�oW<uf�"��	�:�1��_�?�����+C�\�;���Ex���'�51�
����$�D�������Q!�!#O���]�&�\2�,�/
>>���<�����G�{����QO���C,(�����$=����RW���x�k��f�`����k�s@��^� �� hs����=���9�P{��09@H�
C��x��7�<�_��Y�s��MJ~�@�����/�/S�V�����%P�h�P''�W��f��������	�x6ek���"�x*8E���{�Ek��y
zA}\
���aJ)��OUu\X�Wxz�{[/5_0��:��^L������gN�+�GFh���S�M@�����=���!o�yaj���io�	�A��	��J��,��+��V:�BM��m�_����_&o�mv[���hy~�����L�0
�����������L�]��	Z�������g�$�P��hN��G��b}J�R�����[�qc$�=�N��A#��$v9!@*�|�$O8l@>���e����f��:�XfxW�
ls���-�^����V��:�.���K���f����7��(�S�������]f���-���I�
^%��GL��m4T�j���aw�E�l���1��p��t�/A����(b��X5�v�.h�T-K�R�^x�O��>*9dPk"$(@MK�B�)/{~��R���)'	�z$APQ��$p%I5���L[�i�����KSLC�p�Y�K�X��st�F&K���j�����M���2���#���8���6r��&="H	<�}���m$5��l��A�X�A�D�/h<��n��7[��f����
@Q�6�D>���2��a��=��l�N�'������:�:����p�w����t��!���,�������#�t����I��EMb�-���pGTM�����3@��0���#�����!R.�}����]��l�t���n������e����%x�d'|v��/| ��vp���;�=������C<;��f�������hb���0�3\4W����?s��-�U����!c`�"i�P0i�PT��r���Q�����6�m ?m�y�}DXx���b&]Z0��'P����q���a�n6^����V��V@��RGx�9�U��~��a�d2����3���P=�q���R/��&�e���lm��WW���oBqgN�#����d�Wl����)wvq�s���+D�<�!#IU�<����9)�*���*���s�����������Fv�"��u���� B+�RRtK,u'Q�Bk��`������?
��;��h����A20	�|O�����~�]�S�M�g:��UC���unh��L��h�.��;�,��1�J�>�����}�������S�J-�X�F��-�X��J���rO��b���-���8j�]�%���wT��I#�P�
�4��$��f
��j�����	�0\�Bo$�jo>���xy_:���`�sZ'6����sPv��#�L����t�O���Ya�IC�
A�o��`'g���D���(1?��0U�P�z�q4�<����P�������Q��%��p��ON�R����(rz����������t�Z��L���������)�P�dNVW6M��c�C�T'������(G:E~e������/����!"PsW��Nf�4����yW
���C�o��QtEX��6sJ��x]���UJ��M ��Ze��*L`Za0�P/�eT�j���,/	���"���7"���+��
��$�b��w
����.e���`YE���M6�tB��3�$]T�x���~\�$&
�Y��������cu
�H��[1VZ,���\����%s9���9t���$��2���G��gV�.��r�2f��/��D	Jjr�n����l�9����(u���"X��	���C`�0��@��U(�0�}r���b4J�o����YR�1r[����7
��������X�4<T�
t��$��>���f���:�/@)�K:ZKW%�D �	�o���
����0��������Vgb����G��|�@��e���v�da����mL���i��'��a"#��	x�g���xLu��c�z��iE^�f�����^�b�OI�_,���g�q�����a�,��tNgi��\�%���KZ2������u�q}s����X��,�_:J�0)����^�L����\e�����Ni�ns��L���Q���4	./����<�GZ��"?�G�W��e��D�/�&�����h4��777�^����z2!���	��K*���7
��^U��>"w�)�D�{%FH��H�fE;�������~������8QHS��zQwq�b��C-�������\���rw�NH���:;�������Zr�B������c(����f]�����[~=iG��M/S�u!��Q�#���H����&�zr+-���e��.C��	����T�%�%����--kv�y��P��Kh�����0�-��d�����S������_��$"�'O�8/��0��`��������\�K�S�Z��*t9��k��	#r}��GCA�K�PA�6l}&�N�"��s�~ �z&�E��&��q6����L����cC����=�g��-��<�\.����v�=����������o+�����l��������Wx;�����"����x'C1�M�7�����c�H�$YJ%�d����m-i�X$-f�Q��%=��q���W!vN%���-:����q��M=^rJM�h��&�j�X�rl*HSA�N$�$��J��|���.��{r��J���;�V�]<	>K�����-�U�l�P�lI����>+�`��S�����u���U+<�<��fT�zu-�����d5G3[�Z,����]|����;�4s]�d7{~ �������������8��%4Ge��1��3)��rFZ���j�Q,�����&2�[�t��*-���"g��"�a��S �����������Q�49�������enr�I(u�F��/���R5I�N�|����������:�W8x��A���c���l�l=1B1���A�V�NqY�Z�X��ZQ>Z����
b�R�
>���:1
*�����D��$A/�����TL�M3)�'�p�|s�VM$r�V��0Db�m�P ��������BY���_�.eU�m��g��|���T67U�9���&K����7�����y���)!��y�v�/=q��$I�>
��5p��6��fZ8���u(�qrW'�+3���������d&?�'�
>p�����dtE"��N�����g�����fE������N_L��Ie�4L��as6�?p�f��X�R���9u��9_;�d������[U����71�e��$k�a������Ek]��wa��������hoW�B�v{��F����Aj^)����2�W
|������������W�7&1�9���uI��jl��������3����g���P����.�UT��>���""#��A�.�](�o�}����p���|k�TuN�BX�jHZ)0-88����V�c�������C��B��kk��k4�Z��Q3���^?{p����������<Pa��a�:�x ��jL��aF�|"o:�+�_�vk� O��:]���������?���+
�����������>�bjm��XVC��5��xx=�X���w'
T8 ��t��K�!���'X\���c�������l��Y�P��% ���^Y���T�'N:��a���x�;�E0;���hS��\~�����7��z�L'2`��ki�0dn���Bz�����m�n���7����Ny>�FQ7%��SB|��W�<x
��{-]�z��p#b��������7_A����5������l��.[s�8y %�NqP�J�;
�:��pJ��#vV����
7
������[4b�w��R��/���7��6�	P,��|�����xg�m�l�Ol���R~��n��V��N����_���P[�g���������3��W�������>����Q>)z�n�j��e�
.F�vg���R�����������.Y�_���
zE`��:�w��
����)�z��h����D��7
���{�3�0�a���Y@oK���P�a{���e��}<����p�`���4��k�L=�+�������..0�?�TR���+�:�<�3 �����H�J�������y3�<�Da��3@o
@�c���pa"��Ie`��3Z�F�/�[��[�iv�Y��V<.�hU�+]wtq\DX���w�?��%��!���~r2�P_n�5�V���*��>w��UIBh�8�������Z�9���v��~<�)�p�azR:{��]��]�N�S��u#\Z����+�!�6���]������-�������{5w���$��=:�����K2�B�����([}R���-]�p�%�����J%E��N��e90�)���eG�$
@j�:�e�*Zs�j�iS��
���� L�����E��Z1�V�a��z;z�_�]q�)��F���_:o�%�0j��N�G15����!��������j�I������1��;G��v�s=yO{�k�������
0�*�MX�T#����>���z�4�M���y{��0;���aXzM�8�����q��U�����W�����R�
���X+��nr���
<��0��n�u�Y�n����Q8�{A �^�;�-- �#y[n�:o���p��L�.iY����w��]����;�+e��[��?���Y�F��4?������H�? y��?�x�o4�~3X��$�3C!��`�?u������[�'���9M���Q�I_Z9�;��w�i=i�4=5�d�
K���������yN���|:�?G�^����u�_'1]p�O�(���M��
�=�1���J�A��y}�0/��.� ��C�:z�KD1��x^u�����������Bf���S�"�'�)��3.������C�����1�I���eNT?P���J����_�=�()J�(I�G�cU �g�h,�R�2
X�����M��������E��+�$�g�MO*�+���?�^�T�Z�8yn|�������I<��g��WM	�����qN������|������QuJ�:�M��������x�,��<<L���%�!�����*#]��������.0�uR��z:���8(ip�W	�7-x��7�%� �`?>�~��nL=���.?���~�h�'5���N�r�=<T������k{��n������;���2�~��a��L�7=���?��4BJ���uG�����p�#������4���<V�]�2��g��63	P�j�(��u�j�:��#����K^?�����K���\��pPLs���x�9d�8��d���������j�������!�����g�D�&��K�X�q<P����G��y<�H�|�H|tl��Aa0�������E,����`���N�	�:��;�ja�)n]8f%��*]�F��?�� �W�k���3_.9�28;Wp"�#�|��s��0}���l>�5��A��\&��`	�������������Eg!x1��16�� ��1O������i�Q.���<Fw��w��|��Z��U��cx{
�E���7��i���X�7�b��7����{S���J$?�/\"G8+�
#��q6M��:LL�����D���p��K��]����w��Ce9��r�)�e�9�����Kmw��\8�B��>��{���3�����X����4��^ 1������`�RL�H��Fx�b$����.�s���� �������X�����)(#�k,��e���|Q�n6��]��V&�Bx��s2��l�������E)����
����%B��.~�t�.�&2m�M\+M�Nu�9n�����:Y��Fs(<�03J����_��k0J�l�2:��w���hT|oc�
9@�"{�9�7������+F��j�K2�#zQ��w#�������R���A;t�Lj�uE &�zW6Wi��5�b6Y�aS3,�5Cc���-�fXdo�3\��Y��t�9�E�.V������Ca��Y����h4&�Z��d����o%�@�E)5����eR��;dK�~��da/[������EK�-�J��@��t>,�?V((v{eY�v}���������������������9NM&����n��\{�h<��{���Yn�S�-�S�H��>�����s�����L��$����~t��F7u�M�r��%yG�����NZ`�����'���5�;�������Ys�lQ���#U����0����,�dxV�Lb�������O�vHD��|{`�s,�]��K���H�G�3t(�'4M"��Z��
{���������n�<��e 6�����a���y��!��6��L� ��J����%�� ��cLS�i�d�AI��'���S�Tb�P
J8=
��\I�A|�� �%XX\�:y]��3 ���{�L���r���r���F6z��6�����r����/�w�7pw�yfs�y1�-�4����8gOO*T��y�?-��������4�����K�?�i��u%d(����)���_�z�~�����2�,+��d�pr����
�I�����j���Ns�c�b��<]��o�%(��pi��	�V�~�V%f�l�R��W��Rb�
Z�
�">������y�V[�.P�{|������o��1�&��k.JY����(��n^�r�:�����"
b<^'O-:�����
�IE�1�ac�EW�����^B�~�5y�W��S#\h�d2.c�'��x�Z���f��O>qw�I��\���G����A��	�E���X�=��0H��Bd��Ps��hE���DdIh�06!O,k���������Wu���(``!�`���W���)�!��
��@Z��RLZ��wn�MQ�9l���,V�F���Hn�Lu���	aGl
]4�Q��A����{uA~W�����0�t���	.�l��V�����a�o��
�]AQ4��
�
��[�W��E+q����jT]WO����D|~�;����j3���K��	�>�
>^���
�hU�
�{��ZT
���R�"���pX�>��{k���R��
�F����������?��z?��r]<it]�M�%]�������F/��%� 9�1��xwy���an���9����-]R�m"��!�*���J~�����H��w�i��T�v�xN��#�g<�>X2{�M����x���1���6��KGwx��w���w���#�TX�4��Y����6��-�5��:2�;�W$d�����Gl��t��T��%�`Z�x_E'b�
�l�����
w����#m��Hm���04��W�G����O���l]���g���z0�=c+������@.�n��F�g�`��,����4a�����`x��>=5"��#*�f�IE���5�
Oz��r���J�
��&����_����!��|�bB ���pp�n�i���0�$�{�m�2����OJ=�Q�g�5�h^mg'���r|��R����Q.��Ny��%�D�4��w/Z��Gth��m����Ep\�D����f{��"+��k���8��o��[��F��g����`k�N@�T���Dj��?�$m
�F.�u�[b}~@�\11���\a�qz�L�J��JT��W'������Q����?P�liE����&�����0�����Tt�$�.xq���v����f�����{�z��}/[4����t��)X�%w�����Jp�M��$��������r_aiW�����+�Bi��W����0�*���T4�+
�n���k�(+�r{���Bk��uj�e�Z�G�|�+-~�� ����h�b����,��\0+��#;4m�-������z����gb;p�}/��K+�]�M������S�Z��1j���\N5�S�b/�R���5���[�X��U�>������)M6��o��V�����Gu��E����+����N�
�8�og��[]��Z&�q��g���s�D�5�_��%!�����.i����\>��*�?��`��8�� ��������4���z�U+~o/��
���������zff�b�XJ+>�-�k����RmWha}�F���F�U��UP���R�ua�����_���v�B�v]��,�a�7"�}�*s}����*�o�t]����
qZRrwS��-/	��[�"����.��J���~���%�g����K+�B
����5��\g#|.��+�����GN���f��]0P�"��������gl����+*W��rw�b�7���)���Xk��%���������J��$1�>�#yJ~$������,W���>&7��B3r�����v���K�A�F�r+�D2�������\r<WrT�P�������V��K
|P<�(m�}�X�k�kJ�Q��
]VD�i��*U-����,8J��z;�������������������:��M�h��0.�G�	t�A�
����d��d�Q3���!F���_�s/8��.�KB�����J5x]���U�j�k�!�%��g�z���Y-�mL[��7D0&)���Vk�����[�D��%Aj'+�o���]���QA"X�Z�����["^��"�dq�J!fU�KK��3�a��h�bW�an�wW����s!��UATL�*����{�,��R���#t��y���)]��E�5�zM�������]E�:�(ZV���7�kk�.h\�e"��<X �V�K�0h��{m�}b}��Wf�;Q}���$:#K��(�bZ�
d�9j��x��.;B�{���E�/���Moc�����,Bp����� ����Zmz�J���`,�5z}�Itu���m0"��e \�,��u�O:d������?��xzN
|�;-��'�E�i �4�����)2#O�%���#��6� ���$��I���$.{�3�"J���h�����6*F���!D��*�bMi)��-�����$�=f�'is����������3������%�,N��$���H�v����o���m�gi�x�AS�K�,��}�`huD*�V	�3��&�3!v\T�zu�M�O�Uyj�$�n�h�}�^EU!	��
i�gF��N�/����4!k������=����F�/���3K1ug�!�z�z�g�PD!��^2z��T-��er��1����h���@\�(�5��_&7�����rE�M[�aW.W�R��-hz�������#�Jj�.��rP�uZ�_.�q^�T��������U���,f:��w!v�����te���4�x�V��������i��H�K�����B���B�7���QZ����$�gl��+���?�8�i���5+�I��dKk�>�]��I�#\i6��M�}�7)|�6?��=H���t�X7&'Nx��br�h��J���s���%�����vS��u�I����V����)'~�<�^���	^$����vW]���?S|I�b�b�H���d��jK6����d�6�bQ?_����zV��&��c���5&�Bj|61M����\c�)�f�g�d����O1��0QJ��U�L���������*���/WO��g�d���u+�0���3��^�Z��#��IC��3�+s�=n��-��z���T]
���riR���^��R������`��?Q���L$�� B~����4Co+��
���S�h�����NF~x�e�7�T��Ja�%>�*��������hIe����\�����}����\ggj����g��<��/����c�V�������\���� T��Mf��<�w����yx����:,�*���@$@Lg�F�]��_�&�D��q��Q����9�������6W0�X�m,�P;��������A�������/�3�H��n��(9�*hN���Y���:�C���m2���1tMN
?��F��n����0�Y�~0�4��K�aFF�+�Y!�}�s��<�f��5
��w���<W4��
qE����bX�< �h+�!o.&-�S7�f�TJ�B8��������<G�I��R�;��6����1�����|�@KCT��>;�vFpZ�)��xD���;�/w3`R.�C�$'�tB^��#�5�mT����%O��I������W'�������/��rwAZ�����u���'nr���D��w�p��j�����v#�����7�<���Yn�%h�w���R�����
���y ��C�y��9m�����x�eGT`������m^�=p�j��"(����~\���-��������o���O�v��?��i�{�n,�y���A]x�@�p��������+�@J�Uo����L�_���;�?�.G~@�#P@�H1�����5!�d��9�]�����	^c4g����a�#�Hw�1�o�`-���/_�����|L���R����KL�z
XO��zf���`����_R��<	XK����0�a��/$��e(mJ[��P�j�Zz����q����I�Oz<�83
�a�����9�#Z���}W'S�A���#:����&���9�U��i�����+����%\sU~��$K5}�;��H�h9wwu����3��	�4��	��o�������zJ[U� ��jFv�^�R���I2�*u�m��=���xZ�e���r
��9D��	�g�����y~��.3�*[nP�
�
��zrZ���%�%!{=��� �� �7M����R���t�����]��\�9*���w�R���t;����I+�O�Rj@��o
��!./�6��|���%]V[���8��+-�}��3e��dEP��@�`�#��������J�TG��3U\�.�_�:��p�X��m�}�|���s���,���z��4���������B���I����&!�PvB�z�>�?�~��I]M��R!��������h����/���\��JQ��<��;81��`������3F�;fks���T�J��I��;�Y!k��@���p��LX���
��1�^v!���!'hT������*����1V�uw���q ���#:K#�zLi^�������Fh%k��d����?LgW��=�����]���P�� 1�{f��N��u��s0�rpeT�9����P���qx`k �����I�T��d��b������-���3��s���7�;���W��BU�e����vy�w�3������T���BLz�^�O*��#��\$����*<�d*�NAK����e�a�)���jI,R�)�T�U�LjI�J��R*�)K8����4�����Yc�����
�0���9s	[/�DcZ���7������b����%j����_
^JV����u��s�;��~����%��vn�?2�3��q�gQ��&k
�q�?�a�U-�P/,'����Q5���o��3�3��u�K��H*����]�G�����3��e�0WwM���A-���5�{�h8�-��Z �N'��O�������i�&�[q�4@%e�QmH+������	�6��m����Qi��.O��}8x��2���f�W�����b��$Mj�?�������9-2��"��i�!��rm��1~qc�9ZszV���rz�<���="��7�I��9�J�;|���\�,�m��5��m,������s�5�������{���]^O����q��
C�.gOOT�����l(���v�������`~'����u>���^k�����X���0Th���B��T�����j^^���2�|�zd���w���G_����7{����+��2m�T/k�o���y���Kx���56������J��8
�(`�FN�`A��t��������-R�R���T�?�����-�%G�~�o�67V= ���.��MJ��>�f�t7��������J��XK1�p
�;������V)�����t��v7h�7������X���Tt�[uW+!w�5�Y�$+��k���t��E4�m����>�]Jw]�M{8�[j�F�� F����dL.�^��G��W���F��e����
�Eq����
(Z�b!P�}���Ob������-���cR'!��A1�F������?s8R[|G����X)�����3�i�����R��'�X $����\���{��[d�	a��u����.�z�{��^2"�-uk��cQ���[%5Yro�#�S���	�,W�o�k�{��#i�h�\�Jv;s^���s��T�x�S�j'�p�kxiq�8H�`�p����W��wqI.?�������.:��``/#�s���/eHp���O^���5�H�����94w����Q$ET�\���E	��|w<��������)Rhy�eA������v�����/��9)�G�pt2���!�3�^9	lj��"A�wyi`Eq���A���@�$0��DK13�(��Y�����������p��G�@>F��:�l�D`f�������>�����9zyx�������cr����*
�O��0�V?H{��>�Q_��o�nI��`So��#����]r
z�,�&�]�Q�e�oZ^�o�i[p[KL<�����������A�0�,���1d���v��p�5KY�}�az�
�D����6N��viN?�����s���)(6��~����h��e\7�QNf��M���?���P~�dp/���
��>��=��?�T�i���
#f17����������d&�:�p���}�h����i@�tV��KR����a��������spLkz����K�+�C�c��5�kn�hA7p[[�0�s������X�~0�]`a�"`UN�`���?�@����js��f���+i�2(H��j�[�?��B%)Xs��J��[L��;y�2��9�g2����\�R}�L����}��Q�6�'��9����]L�����|
��a��,��l^p��T��(�F.��Zf�����E�����(Zk���(;N�V��l�ho{����A�f�e�*`�|��M�j�-�����='g�}�M�Y�2]��FK�G����sm����3�~\l�����>BGm�����{��7[����=�Y]a�2W�l�aF�L��]���g
��`������>��U@���7�f�����I���)��MEj2��!u��b�J�0����0��}��G�U/�y��]��'nq4e�Qw��;-��h��2wU���y�/KC�8����{����{.��_�������.=��["���H)  �a��X��������pi�!1z�j'��WW��T�#GA,�U6����xI�
�AL���C�8>����x\�"���.������6P5@��;WJ�����0<�������A��v�]��6J&���(��WE���k��X�&���x*�\�q�:��?�/�/�}��k��x�l�K���F1��S9�F��{8����s�GF:��U6�oJ8l����,�J}�L.�/#��<1�a4�4t�\��E0��]k���F�d��\�o�c�V�uA��!�������������_���XL��2��K/s"�ol��/����^�������C*~�Lo�
���S$����Mu��*�����`E����@]ne����$Ngp�h�#�'��Rv�Zgn���k�t��W�x0���O/F4������}��B���E�+�����[�8�Q��,�h���zA��#,�H��s�6���8�#~rWe>J���j�X?���$^RT(���^�b�x��^������;XB�4�#+�h;R�������q�RBG'��	b�J�p�|����xR
�[�L��x��~���,�=�b��OC�X
!�s�Y���|�����Z��&=�AyI��-U�M�~������w�Gt�����=3B��u�L��8#i)Y_�Lx�����z���}-��=����~z���[��E�'��`��Z�wb��(�UA���=�u���:�����������������CY'��$�eR�9����`�U���D�a��@�n����Pm���vO��Tf<T��������AD�=����t�����v/�����\��c���?g�H��I�$a
��jI&�)��,�z��-�w
���~k.D��<1a��������A��5X<���b`�x_���F��w��>����$�K��?�6�~.���;����9���@K���l�	�\W	��*�e��r��u��,��n����C��u��L�������!9�^�)M���0%i5~f��y�C�J�'�2D�I �N�H�Z����
a��Uf�}���������k��R�a��;	!6<�x�7Ee���{x��M��e�x�Q��Nn��-r����T��,�H��������J�|�+g�+k��=L���=LJ(%��`�/�{q)�����SM���)�&\�{�uR����o{y�����`�X���l��;�uz��E��*�"�V���m)��B�I�4Y��R0�rj~j�Sd,vA��?����}G����8�LK`{2N?�rx��9"/#�Q�����[1�`0�!K��l'���Cv�Yhf��G�q�P�Y���f���u��G�������N�^��}���2�e�i�����'j:��cf:@LU-33BDa��"E�`���(���d$��Z�#��~��E���W25(��N���\�DJ#3��� �Z�A�=��aL�+q����i�5 Ud�s�3C��SN�������/'	�@"�,G����x��T��P�J��y����|5��Y��Z�.X7���$+��	+����-������p��L��W����Te���'w6.j\A7~-*P����Aluh��@n7)�TV��9�I���\J[s�r�����"P��fNu���P`y��B�X� ��t�,��������Rp��
�`�<��5S[3O�d�Y�1�Q��*������z]?�:SH�#p��gK�}�)����3~����b���>h��R��d����e2Z����
h�-|�Q'+i
�I�gK��I��b��5��/}o�Udb�BJ�Rs�����������Z��r��Q��I�is��Ix�}K��"���$�K���}t��y�����n�����?	����+_R����nv}w6�*f�L[!�F��X���H|�}t�w�G��t]K��
����"��-a�e����DHl�6;�����k�s
��5����x��l-IP�_j�gse�SO3��[��j�[���cg}�j{����-u�1�W��A4��	�g�;�\(yW������`�����j&��L�d��6��	�e��v�J&��a���i��R|�+J������>:>����2�BGG�
_�x����;J{z�������(lyq����-����n�S�
��4�b�=����
vL�*�r�W'��q��������:�O��@��e&1���"_����s�
�b����o�L!�Ozy�K��`bCg��r2���T6��xI����rn�t�9�6���	s��9����%��w�60�xRV	dGZ����r'3���Pn1�vy���������'Q<�I%��*��x7;������'���6\�&���3�~�����B���hs��m8�o�5�����s�����*���O��3�>^,����2H�h
��N��uH��a$���IpC���|_��QM�{t����� ��r69��Wun��"[ �3�e��%�
���Y a��5X	N$���s%
����E�2D���0������%Q��(>���z��,�B���p�+@��������Gl��R�25��hm;���c��b]PV�5[l��b]���vX
z���/�9m�6u_���2���wB^]����xD��\��(h�KR��&�i	��`8�2_-��~��_�=��a�n m���L/H��	����u0��?S�~pif��#��5�m�(�'S��&���Bi�st�2,��gph0�uC��Yh��uK�9�H��f�	"K�sJ�6����IM]����T����U�;���Ri����]Fq�9?9�(�h���#L����������OJ��}����#�>��/��)�������y����N�����5s�);����9mS�T]�m�iZ3�,�4�8I����y6tfx���R��j��$���_��so4���A��{��,1~a��S�>&UA�<e{Zi��������q�R.
�Y<tpon_		���Z�h;]
�[^Y������A���e&�[*���������Y����h�=�'�����nJs�(�;f��j���"�4�B<[�/���1���'3���(��@D,�*�� 0E?���0��Z�K������)}-�!��7�f�@wp��HQIu#t���������iR�0=�~����\<=�,Ti��8q��wp�9:!{'�j!6P(��+G�(���R�}?;�"~����������;�d��yj��su�b��2����M�A������
�w�n��^�y�`�K���st�\��=�����T��J�.�0����%����4!�}���"��oz6�|����^@���5�T%[^N���g5<(X��k����K����_9��;�~�������B}i;f��M��R*��Pz����M���T�H���~�mjL��:$'	���S��i��oL��25�N()L1~��Vv%��IA��m��>�_8)E�
)�����|�+&�$)rOX���1����HJ?���s��:(���_���u�������A
3K�Rj�z����Dv7�������	�R�mZ�������}/��Im4��[�&R�[�&R�[�&R�[��|���g=*oG%����:q�N�h��cWg�	�����9������n�<8)��#)��)��
�w;�����L)�����b�@��l�o�yt�����G�5��xt��������2&D�� ���	H�h��N������qj����/t�Wx�XLHe��{�dV��j0��@�qw\���L�
�����^��&9���'i�/wU���g9(�_�[/[��88�,��p��&�WZ>�o��5$O����V���L��MV��-���Ba���b���1��[��
x�Pk�oYs0s��O4������k��&���z�������3��0��q���z[�+���P��'�UF+�*Cn������'���)	����3X<�D�(��Q�Ie*���Q�z�����`��nH������h��(�X���l���Kt:�ZZYYq����U���7�
�C�����p!���+�G���98����i4��"��������K���2�_��;��K���C����x����������Oa�;&�L�!����V����/�*�NI�3���`�!��f��"}ieQ�H��a�\��_K�4
$D5��/�������F�F���Z~�@�t ����dm���T�����d)L^��S�����>\�����&uK��n@i	���`��^]�
E���3a��5r�PniDi@��r��DO�~b�F��o5���g���3�I��&,��z�vE�|��G�����=j��>�X*���z'��VO���^]j�����Dkm���:pF�������Fc����AX4 �&�����z�v�mC/pK�aD{��,�Y�n�����pL7_,-�`4�	��H`�B|����2W����d�{:&������op�V8z(S���l��b��P.�b�R,-%���V����M��t�>d���5�E�������-
��h
��U����2��6��[�O�eP�X���N?Sxl56a���[J�w	����,��)�O���:�C�y
] ��|�T�s��T��<-S�t]��u�wF�:Nf��EX��h6���FP��m�E��(g\p�.Y��l�R0)g(%9��e�;���r��B�:���Ll1�FP������Y��_������B4�����d8�H�b���T{l���C�/wnd~�=Wq��+�\��"���]�jb���������Hj� '�Y������0P<����3<��ZD���K�A�F�r+�n"d�tI���'/��J-��F�x0m�p<F��&]�n�iq��@���K���NG�����:��a�6�d����N�������62�Z*.�X�$2�jB{j�x���Hz�(Y��m&'�k��I��+��,����S
�CO��1��(����H'+�.^�����)_����?��#y��$,V���`nmnX�W��*�j������Y��G�R�C���}R����P��!����g���RS,�g��Q#��
�FW����@�+��?��,<([��@v;�������Ay�!�j���~��Xm��~3�L#��\�xK7h�����$Q�OR#�_�l��������?���9%�|4���=$jdA������*a�K���+<W(����p�)�6;�m�k,TF��(�(Tr��-����W��uk��d2�TK@����
��=�m!��g�c!���L�KDY0'0��
�5g��B�d^�g����Y)q�j&���-9���T�Y'N*=+��
��������&���C0E�2��7�r�"
� (Y���W���B����5D`�
���R�w5�T1B�O�q�$p[IA������\=\�?����r�p�����,��8%@�V���&���V{k
N��H�4vk���e[>���(
a��`\a�Y����h�RM#)*����_������#;���C{{�������RO-��r���a='��V�#q\?�1/~��u��,I�.��gw�eT7���'�NT�2����*�VL
�gz+L?P�V��1	��z���z,x=*�����^�Wi��B�I?�������O�r�7t�_'�3)-��g���&)�X�"D�B�}
�j��N�-�������@��v���-1+��7{'s�%���,H���@��,b�}y>xT�<7�>��	��J���,h3h�A�����
6>���moa�:�`0�!��%,��v�����j�
�l���F�<����(�9C������!h-���Z���$�_Y�9�b+��1�?+NvC�|me�\-Y�U"j��V�
��p��O��Y9?,��ss��f(���6XJ���j���E{����)`F�-s�zs�.4^���h�kf�V\��f����������q��j�P����(� ��/�Tv�����6�A�Uo���l��7�(:�K�Cz���k�M+���@����<���k�� ��mZ��	n���n�A�Io�L��x�cG9��J���"J�oo;�-���p��)����������l 4�"'�Jy����*t)EWX�)|g��*�����CZ���n����:I��.]��Ib��=-���xZ�e��B��D_""�g�+d�����o��e��B�r��-G0Yz��u�Ywz��;{�L�p9|W@P@)�?�7|Y���8����u���LY!XY�+:���~*������Nmwg=�:�m?YA�����/c|��^+��;��	�i,�:�������sq�:�~����Or�:-���C�Y���h{������9i�ug�g|�!�v;����HVr�M����N>d����u2��}��0��.a3�	b���BFK'Cl�kT���`G8�����;��������c�z0�3�o$��&�e,�d�����(u���N�������}��N���u�����.;9z�Q�9����(�J�4�����f��`�O.���/_/�/%C`>����Qp����;�j����l�\]�_D�s�i\z���RAo
�e6���t:�E}���g�,�����$��M�c������/"Z�j
�V��7K�S��T���\?:iF����<x�Ie�r O�+����4�����{���>�l�'Qmz[�&z(Y�{���`1���;���v#�z>pM
f������5���s1@%�������=r�������a?4���~[}�fuw���l��Q[q���l���'� 5;����`�}��@*���B��:�������������
�������U�C������I	1�g��l���w���<G1��7O�)f�w����y�h��G�j)��"��6[�F�y��������'���V?o>�o���5�
7Z��E4F����v�R�hp=�Z�����B��;�Q��q5��F9����j:Q��3�
d�r�U�@.bxbW�o@�����sDm}8����-�~����e��S'�����0�I4__|�����g'CjK����`#V�4�ehD�,�a�����R��'���%@�3��*�Li�G�6�C��8���5x��;��)%e�>�(�n�a\8��/������Xw3oy-�^W^�����5m�����d�D?��rsN�rJ�����.(/�_/	��P�v!���_35$��_�R����[�gQ���K=?�P+O-
��0"���^�����������(@1����5t)W��������2u� �]�-�=�~����\� ��HaA�NO��a2�O����������#w�[y�nk�*����Lm2LR_�
S���+:K>W���F{-7sk�������AKV?���*a�3�D>[���%_�$Mo��o5[|�a|� ��/U�X�@XN�i\/[��p���1��P�)�9�r����Ay9���������;5�f�����A�k�6��s�k�����wK��-����x��������K�j"8�S��K�P�����o,��i�w0�R���.1����4+S}������"������T��/g����	��go�q��x\�"������*N�V8�~n������JY�F X���P�-���^��SJJ�����1��@����v��"��gE+J����<�
���s�K.T��R�6�x"�gE���e
%Q����1���^X����h��'@^vi�	���m������n�;�������:��[���
��
��h��������8�hs����S7J�+(5B:�x��v}o����O,�$�X!����<�g���eY�&�����By��vQ�����=g���*��A��� ����S#y�d2��o�<���,�vc!^	C(mZ��ZCE4��������N�m=k��<�P*l��S�3+�\���#�\?�#rf��*&���5�a����.�p��l<��)5�f*���L�3�0*�d������nZ��.Z����+5c�2�+�N+W=�L+W��Jcp>��	�Y���:6�:a�r�H�k���4M���v��O�������6a��d��lV�\�|��t��n0�i/����d���w��739�e��GX���S��wM�� ���������2s2��h�l=����yt �Ue��o�K����	�I<���}�[����m�YhilO���X�v;G��od�Zh�������MF��v��T�N�xM���'wi���~Jm�'j:�G�z	��h�f����!~`�EX��sBc���':���n�xgvH|'��
E�>������3��L���5�<$�(T5`��;Z���	�0��^���s)�Vp)�9���"P�X6���M�0����?�?k��)��w�1�kf����j,��Ym+��%Sy[��@�*4�N��`����o��N�} 4��m@�_H�Hn�t��~��fT?F��v5��l�U�8��,�bln��V�E��Q!6i��A���������l�.U�� [���CVIf!~�"�L� �2��B6=������
�TV�=xaW�����~mA�_&���?9��
1�3&��_G�������pR���'��_����_	���DDQ&1�����a?`%���M�
3����F5�9��vzX�����:������,��c�����:��kp����R�&�
<H3m2C�v��������5��1���c��Xl�d^zB
��@���������"o�<s�&��2Q�2�f���L-b�e�[���.�V�zL��j+G��|�\����,���g�#5��]/��S��A����A)%x����;���K{3���g������l�*f�%�sY2�(���d��	7���$�Z5�2H��7����u~1��n�t2;D1�6�${K�������+x�#�+�O�'��I�h�H����%ip��#�G8�d��2��2���3�����W���uS%�a��[^��'d����3�TB*+�K%M��y�GE����P������|�U/��F��oz6�	���^��
�T�DS�lyQ8Y��2��y%�'�����2��<'�'3�[�=n~��3���qny8��	��k�y�<,-����Z]��M�D�F��::�bF��%(w�a0��`�Sz�q��E�
��S2s�,[�T����e��9{2&���A`�
Q�A9����%���h/-�5q��O
0002-JSON_TABLE-v45.patch.gzapplication/gzip; name=0002-JSON_TABLE-v45.patch.gzDownload
�1�`0002-JSON_TABLE-v45.patch�<kW�H���W�p�N~�y%�L�,��m�����#Km� K�����U��RK��3$�={���-uU�����YL��k��k�><�6v������v�y8�����p��?���m��>���>k4��?��h4���sv�����^{��8�gG~�����O�@D�!�0��������l0�+l���X>`����m�y����Fc�?r;z��y��������7����������^�V���Q����Y���G��R�f�c�����������x�Q��5���|f;;
V���3�0��;�;u;�L,�u�i�Y��`a����,$���8
B���4
@���K�����86O�XC����md���$`v:C��".�`���H���b�[���������Y��@q���G���<��Nsrj�������/��X�
�6�&�Y!6K�"�?7�g��������k�/4���@~��hOY������s�"'��
�gEn��$��*"+��Q���#�u���H����7�9'j����S{�����mB1���;� �
��������p����[��� Cw�xZt�}��R����sE�����r����J�h�O��k�h�c�����;��F�������.�A~f�{��N��V ��W�@�!�(Z�`� �0���������#QC���'��f��������
\T��,J��
�r�����&dr�g�%O��Vk� ������Vo��Y�/��_
�����{����Vk�n����"��/�b�'(��'V��i�V@����dp�M<�`�(Mo��_���>�
�D)o�������~��kI!���{�J���M�`/��zA�WW7o���*%����me��DkP�	0FC%��f��a��dpI��iB���P��_vo%�8��{�zGlKp6�!������'��g�rA�9\pC�X������k��Fc�lYY[*Mi�M���>�Hf�����^�-z�D�v���7�s����_��/7H���Ut��b�6�aT��wL��/�����������c��=�R_���`��x��f�|�+rxyrHsyr�Y�'��%��'���G�������zJ	�`oO
>T��$5w����U~i!����1w�  �����Y��af���1%�{T����d�zy�|$f~0��o�,��X�B����1�(��A���;��@UGM1�w���(�"�@?�j�������Yxp�����4scB���G�a`��Z�vTOg3>#o'�����}V� fPZ�ru=� �
C�7��b����\/����8�`�>�y��:�+��z���o�(L�>����2�9;�"�
�i��kSi�G��r������������N�������e�.�c�/�;�<��h��{��sb��I��[��t:W0i�����r�t����%���/�=���H1���^�������i��}}1��u�����w�^
>|��Cn��O���n�m{P`Jp��J���
���$��IJ��]Q��z�9�����~e"��!w~=���� �|���9k_�����?.��/e���tN�<m��z����)��O�����
��N��A������J��0���*��;t�R(���C2U��.�2Yr��O�c�#�6��Gu��9Vdi���0���������cz%�����*�a��cf[>rf�6�wh�F��Y!��r!{������A�����]�����w]wb��V�L.��`D�'���pec\��j�� �
*��ue^���u����8������4�*Ky2E"t�V������E�eGt3�4K�0�Y8r�hl%<���Z���7������*�Llb��ZDa�kE���X�_�J�x�r�YQS��{�i��9������4%�����aJ2�`�O��s��@9uLLA�s��>T��X��M�ZdMI��y�C]0��\_�h4�����$���t�@%,iC�3b�h,��z��0C�s��p�^��H�d�R�F��W(�<�C�9��s2!z
5G���
��������a��b7D�q����(���}���P.�,����8����F�����d�}<T���M��
*�~2�:3�-C�Y��&#������R/P�y������vbAf[���c8�=v=���~[A��i����0�@E��J�L����H�:Y1�I�4@'�����9�<���4�� ��rTs�(���@�`3�N�� bc����>nCf����b��n�w���u1�Ptg��sP�R���Av5�P�\f,�}�f4���66G���N�de�P�l�Q�p��"
U���B�G?	��a�l�O�Q�#|(��������siJN����z��W�H	Av���IYj�V�K�3,���	mf\c]��bFC��e�R�G�v]��Y[M]k5�8QT�!J���i�	1v��D��������Aw�����e*_���,yF�U�P��
�)�jHR�#�@DH���g,
@I6��D���T��5��P���� ���D9�����h�>��wQ)(��+P��i��~U���� j��t2�SV%v��X��"�TK(Q/B�,RRT�[!M�9���C%�jQEU7����J��l�rto�.�W�PM�p	�9�,YN6BT"�o���o#�>��^���D�����UdH�|VQPc���D5u�3�����W�T�j���.�-l�]���`��>�)5�C�n��O!��O���*�Y�����,8("��0eE�R%.�2�Q�rhA�S��B�4"��r]"J�����Z�<�|��s�/���|�gO5���R��2=�B3_2��fT��p�Hu3
rFQ���i��iP@���I $��$Rm��3�����]1�#��P�G��d.�8�������^�~�I�S���d����%A*t�C��V|QSZ��y�MY���i

�N��7��r�,���gM�����h�(
5�AmW���I��e��B=�H�,��ynUl1S�d�����U��!$s���� 
r�HO=�����]�]S���	�:~X=q� I���5gfL��3Y����5C�-�-_,5;F[f}l�+���}4O	�#ZFR�> �G�e+�E���d��Q�\���������b6>
H(Y���#V���A#�nVbY*��
?(��Zw���@��"�S�3��I�\���l���|��x��VAL2�����0�����S�,E�m�0��������`
y�Z1��O��\r�0��RBH�~��B�x�uK�v%�%�����R�}
����AK�+*�M2pj8:�)��T�"�_�����_�{��^�I�E�����5�*�sA%o��m���vO*�Q�����E�<�I��V_�UtP��s�D��V��-7s|�0�����|�9���wU����i��!Q|eq��&AK���T1����J1b��>�5��6�z-�?V���������
Cf+�B��P��r� ��j���_�������w
��no����f��
�x=%tv���\�����Q��A!�M���x8}@%�@����0��P�r�M6S�).��s�E��Ko�(H��'�'�%�3"�I=n[����eK���H"\|�n��p��V���@��!2~�O$g
�G��MK�pp?�wE�I�c�����.���(��s��.����K������zp�������dc�����Yh�E�10k�-���cdI�H-��v�%;���;�d7v>%R�G������)n4K����q��Kp�q!@������!���z7%��R)�F��#7`�L<Z��5�C���--}�/�Q���]!���.��eVr{���i��!�O%.u�|V�V�V?�V���w>�);�d��/��Hq�e?���������L����$�@nn/��]z�D��h!OX���'sG�l��0V��w���#�2�?T�D���?�����i8���[i����%���l�!|��-�T��o��u��
���=K36��:9������eHN��$x���iV ��.@�$�Y4t���	��1�����M,R>F/��U��_������*�~����)i�����	5�8���W��	��|f��n�=����N]�!{�	7���o������������J��q��9��7���F���;�����8�g�!||�G�o���NhM,y�C���3��wnh��a ��P��`�I;������a�o1NC&wv�[�������P�hw�}>������F�9���]�B��]2��a�5��}V���x�#��M=���<H[p���s"
tQ���m.69b�'���s�����j�F�z���_�d�AG��������U*�Z�{�6>M<y�T���$l���������	o�op6�����=j|:{�6�����*y�ZNY�H1��t�s	�l�(��;Z���Xh1E/�.�O^��������F��C>\l3E8���hZ����.� ����j�}���q���A}��P��<�.���A6��
�$�S57�/��L;��qj^BpB��%5�"�������T��V*������uFm�GG�'x�������N�(�l�F��+����6dm�[]������C����m���V���������?���$c�Z��M4���B����Z� {8Q���z�0s�����k�<x��������A�<_pO3{�Z-�M��2m��&��(�2����T����V��"wW������}){�F���F@�*�3�����/w�J?dmc��H�[��L
J;i����8���L8J���$Z�����j����Ta��
�n4�Rxe$	���n>B����Hda�#%��� �����7)�&�0�:C������48��)�
�i�[��j��h�<�8�Q1�U>lB�3+���d1;��&�W^���>��Ez9	L�������7�6~!����F@)��m)�V��"�N�]tY��[pGl(����8����}!�$��^Q�N��(�v;e^�hI�Z��vw�+��Sy[I5kk'1mq�q�;���5�Kd"���iUZq��;��B)�E�u^wA�$����
�������^R��G������'�+<eM>���n%��/��?���I��?�j����5�;]���{EP7eS�&��K �-��I��?����
��61���`b�Q�Ce��P;�
I66��Hk7b(i|o_���As��Ks�e�C�����8��y�&�&)�m)K�w9��������{���nK�d_a1��vp��U�%O�`�����Qa�Z�8�n.J(����.��CU������9���l�P!{�(Nu�U������s
lc��(gm�x���^�x���2w���������f93}5Z�'f0�=��w!��W���>���r����{��A�eg��)e�%�o����y�-uK(8U�
Q���_���������A1cF� ?��7e����^�����x:
���-� �_��$�p�c��������K�3sX1�K7�Up�,��Y���c�P���c�%�eE9�!�?��	e������H�Z�*�����c�jAKu_�r/����Z������#���.|y+��J
�c kC1�l^�(|A���C�I�D�=G>��u\�s@��<%Qg��!��#�d]]+��DG��2����Rz���@r������J*�%����w��k����/.��;��j8����-m3D�}����3�vcs�^������g������$������%���d�����?%44��o�K��:��?�����D`!���&3��&���'����r�� Py�����Zz;����d��fb��������%2�|�r���O���,@������V������?�]~s��1_�<��K�w��O����r�+W;����^��i�x}�-�w�_��Ju]��'�1](��,��}!�����w���$z=H��������N��l��~������f��8��9��S@8��Cg��'S8��C��`fr��]�7W����D
��}
�l�IfJ���Q�;�1�������N�\M|��Mn.eS���yU���2'�#$����EsJ�P���HI�K{�����~���x�d�I�L{2v�f�L�oK�;���x4:Y��nA�C.A�m�Qk�PR�2����Y%-<)����b��L	��U�Y�0�8��>BrZd��3��!G�q���!(��4XR��%�x��\���Zn� �������Z4{1�]�	�og�kI�%���X����"J����pu�x�"��.���%L'L^/�Z!�������K�u��aP�S~��2<MR2{���$�����*���������S 
�V�x�{�� <g��!��Gw�{ ��7`Y�gs��m���/��.�/�zm/_���J��]�yu=f0�`[]*�@�\DWG�h6�v����
��fm�BYl�y�r�D(�+�L�)������&�\Lm����3�(�Ik?����N�����7�B7"�7��n7Hv'�:�hc'�E�l�0u�+����B��W����e���Dy�B��^���c,�����B��~�G���'�%��!�����S7b����������H%��D"%���i/?NO���g�[O'�U�����P~�����Td	���cQ��u	�Tl�]���T-���;A9]����5��|0���YB�n�W����sn����%�/�x���z�������2q����{8i�����bJ��y�&����g=�{4��\��"�Uj�R�TD���[W7O?�k����,��/���/�D�vo}�%#�����<;S�&������v��a�P������������.��~e�{��1#�.fQ�}����&��R�q�@���A�n�y%5��B������m��
��fVu�@j���?vQ&?�������F��i`�����7�LB[�W���*D�:�.�J��	�I�e@��V��J�k�A��W�*5(#����T���S�V�|^���vo�AW�����$Z�#�]�1��+[n�^@������������bLk��K	g�f7@��������������U�b%��+�?����0��7�n��p_�y�o�>>����h� X��.�5^��V���	l����.���^�������n�5�t�[E��,�(�
|W#K���K��^3_�t%�=��E�y����/g�lF+�fX�O%�������i�\1/Vs>��4���c[��
�-����j�~?>�*bx�P����
8�
H�U�64�B9�`���P��#��)W)zOyGq)�>��W.���#�^�F�T���m�L���_b�H�{(
��� )�d�_�����\N���"��f	��i�%�u%��'�I���o����D�>�Pp���F��h�e���W�%����j$�R D�������t�f#���4q�h�mm,�k6���jskI�O���%	�;c��e���5t�X�|���;�A�W(���^5�(�o!�j����Sh6���
�SV�o�v������R�y+^YX6��
��+���W�"^W�������/�@	s�2��(���D��z�[��f�]Cz�Re�Z�$e5�s ��>����i#�C�^�T3�]I-��i�P�s�uUx��7E8�E��20g�����|�L�>%������F_�K���X<����:b!�1���I���5V�E�*0�����AWiMy��&z4��)� �P;/@y�=;j5�G�:��(��R[t��x�YMH����$�G��6;��i����R�w��~o��1}���9�X�+�u�R��+S(d���<����xL�~Z��=��z������a�
T��a�K����]tY���GG�_�{2+L��`yf'`dPH����������u�6��z1e�8�ypn�����/������*i��[;r�p���������r
`�
,�h�VN%~Eo;�8,�d�4���VJ�&����~�����d���]^�����s�����.�~�������Yz	��K���u��
[�4��Z����&�:��$O]�sZ�_���?|�Ea�������.d���T�^V|5$x�Y������=+N�csw���]%ae�\f������J����=�8���@3g�������v4L�����J�k�$��^gs�O��Ad$k�4j	��L~�L�:���P���9�C)�t20'���%P�����&�a8I;e���aX���� �Y �NX[�]x�����w*e`Yv��O��`(�������	|i�~j��h�fG���4;l=��-�;A{)4�@����������w��i}��lo� ����D�{��<<i�o�~��<(y�^�lN��0���_��2��S����Z�S���X�ug8�M�W
�X��(�5�h��������|�I��N����O
��?=|���#��(����6|� s�x!���\�>9����~�/?�o-���4��p�����j���Bj7���H�2OVk������'����i��a�
�a ���j�/Lx&�x����n/v��O�iZ�����F�a�]���p0P�����?'���/��g�y�l�8�P����g��'�!�H4��s���O�*�|��#g'�G�prx�g����/��i	\��g��j7�8v���p����|��)�l7����v����?5OO%"��[�!D!��a�a����3q��{9u����#��n����a��L'�X�6��~�z~z�8F���0����q��.��g� FY�7����y��%�����B	Kf
������xk��h�eZ� S������jB�^���>?m�SR�k���W���,
N�O�6D���#��[��:�<i��|;z�=:9y.7����b������F����F(�w�mX5�H8�krq%�����yLh��2����)6�7	Uv�L��S���
W�k����NG`�6�n>�n�S8��	�2F���3�h�)��R���D�a7���@NrYF>�'�]ZM%�++V���%�*N�bC�C^"=u�+ :�ay�;L�\���"�>�Wu�������t�A����"������	* �S[Wu;/���}�`�*����sW�!�+�;�rxX;��a��@D"���V�����L�(G�a"G��h�-l��8�h���l�L�4%�7�B�s	�Brp������ 
�|��YdpL��x	���������A!h$�A�n�-%��R�XG=,�e���A��"P���t������,���<='�%�jT��f��-�F���MG�8H���#�p���<|��Y:�f�<��n��eM�����#�7�>(Y�\��v���R9_�U��1B��

J�F�tRi��D��`a��,�`3�I8F���Sp+/Y.��#B���f��1I4����G�T�����9�X'[0yX�����L�{)|�L�3��@@U�%D�����`�)���Ro����:T��K���!�������n��m2�}�3��[uF�d���_����R�T��H��t�F�$�k�#&R
�5
j���q3�Z4aSj��%v���#�:���]tMV1�d��t��0q��I��:�]��&]����yg0��:�Y�r�O�v�������+�M�J������������N]f����6N�����=(��������]6��l�b����H9��Y�C<N�)�����p���
y������e��F�Ti�=�����I
�������M�,���OO0��u��3�*�����sFb�6�;��^���!)nEz�A w��r�m�R�d�}���4*�i:�v��6/�&4�p=�0��{;�/U�:l��P��\�O"�����?o�u�;B������d-|_�U2(�XY_�T��PJ��~I��s�8R:�a/DGD�_N��b��UP{ �^��##���
�}��	Q���h��&���Tx���<�?�E-dP���~
�nr����e�e���2����K��V�G�1����)������+������9����#,���I4H��}�'�@�q��}�kEb�,����j�^.��)��H�{#W����[�6��,�^��+�uY?:<X��rF���������H�]�q���e}k����rx���X�1��3��z��J���)��U�Z*�`�B��El(�M�N��U'E=Y���D�.�o��p�8�h0�"�F��������{��;����� ���_xh�2/���\�����O���/x"�����Z}���GGV9��i����Q�+��(���r�Z
�^������<�J�V]�����F��x��pu�W	�~U���5;�s��G�����#�����^8����]����y��eN�=w"��z�tfB�Z���������)���t��jke�R��/U$�w�Of�+2nM�������f�u���VL�z�J^']N;0���j��������m���8\Q�vI����#-�)5[	mz�11��b<�
��`<�^���1����XU�BA;�������0:���d�!�lq�EI�t:���?��Ag��d�����bz���5d�~aqe�T���$<mr���
��np���2�J���(��^�^_�<��"d�J�AL��ZY�i�(e#A����B�@�E�T��Dc�`h	���iQ�z! �=�=�J���r���A8n�Q?�:�U����:/�~�V^C��"wG@��+�W^�R��:-������r����Y�8���2��������+�Y����3�!��@.�I��.R����R�[��3g���'L�)�s�Y
���`�5���V�M����F��[o�sK�B���V��,��N�M���U^F�~2��$�i��je��(+{;�r��s��k`9����|��$����Po��{�z�9'��7m2�g=�*�O���A�J�hdB�=����Y�%��xD�%���$$��������b�JX���O@��o�����V����:)�9uB��b�As_�����0�N��(!���e_.����6�-�`t����
%[��k�*�`���H\��W6�<��B��{1�������0z��J���v'�����$���:0�z�(8�v��=_���
�B;G�.������u&1
������g��_"+i]�����r)/K���B�>O���8�X��k��t6��^�RUR��%���P��'�7�l�J��7IL��zjX� ��5�(�K��J�����M4�k�
��3��N��������eW���bOXE`��r�D42��Pn.(c]��-����J����8��"H���+�(�L+F�f8�;�k�PA����]}9j�m�2������el��k���N���A11e�mX��W�������&V0�WL8�:�X�G5q��%GM��@����(1,R��ek4D��>���~:��3g���,,�B?��|��u2g�M�<#I���x[#�H����;�����j��H�'P���~��[��F�D$���.����],�s*���VP��.�~`r��9������-1��z`�#T����-�\���|�#������")`�#���tA~���0
N��L{�(�
>��������� �hC�z\�,�NI�5�0T�[gC��`���JU>�������s�����u�������g�0���g���p�[�.��\W���4jb2!�\��"�E����~R���X�}��+`���A_�,=y��dN��d/�\�����9���������F��e��d^�y@����HC2IvI�����]���X���/����w`�Y����[L�m���ow`�d[������,k�A'�d����D|�w���#<d��Y@c�~�t|����T�0AGJr��w��{gX�f��d�+���(Bq��@���f�Q�G ��@M.;��2y��}�hV�?�D-�L������@Sa?z��������5.�'�>���-z�h����1�{D	W?;~2�9#�`�(�D�����"Q �4`v,(k�T�4�����7������"kw����L�v<���<����=s�!�����?��p��AF��%��Y%#���`���>LUN�H��������H�@�aLu(e@��"�����\�{x�<�(��AU>��S�_�3�c����b{��	�-��L���3C	3�,���t�j�2�%.jX��n����E���p���J��+��.�"aK���B�U�������P'W�;P�y�g�s�]�����������|t���<�Zq3�@�VE�uE�.�.�8��{����K$���wh����	�c:�p�1z���3��`��x-k��|SP�fp��y��:�����w��r1���w�q�,�����Z�t�E�'m������&�tE���L@�
����Hh���J,
��Z?�Q�\E3���--��%����B e�	��
3x���wj|��@��&:\x|[�w��[�x�h�0MO��v$���Y$i�y��jb�
�L���&����}#�"��u0Cv@�G�F��@��.��Gsad*y��uy!��r<:��QP�9?R�V���P���u��s��[�c��L�I�>��n���NF�����Z���Y��H[d/�����U��,t��8/�B���oh��n{n�������[4��������RZ���zL�y�������FZ�%x��N��}��2� (����$�#crG2"�|�@���N6�e�1�
�����Z�J����������v	9�N�Y��J�
���������3YT��p5�'{��%��I
H"�Yp 1��E.}���+���0�����i���'�;�py�G��Y#Tz�	j��jek���Q���z���z=�9fl����T��!U����hq;���S
��$�a���Gu����>�$y1�12,`)��xO����H=����������F[��e�|�� ��e��.������NM�_���!����`F`��F�d��UQgO�Z�����������*A���N���������`��)������x�xW���\V@{����,�:����VT;F�����\�m�6�JC+
R��������7���1o�g:"S�����3w�o�9�A4?����z|��)LOON�h��?�Aa�Fna�{;���q^J�k���;�B�$�DW�6?dg�1m`9D���6'oz����w�)�8<T��6�~S=��x��~��[�3���������+>7��3G��Z�8�!���g��������v�Y�L�K��&a�%y�1/�F����:
h��"�o\B���X^���`��X}�:��q��;��F��=r.�D��{�������>}v%A����L��u���Z Fs3�������~�G�� �b(�~b!���+*I���������2��^pF����$�^���GW^p$��py|G�����/�p��@2ASl6�N�%1����~�9��h&y��h����=/��J����/���A�"Q���x���$I��<=��D.2������j���z<�7��	��I��P�M�F�H�����{-�{�����^.g���]�>rZ"2Ggj��lA��=g�:N7�f������8�\.~�����~�~���J�i�8�%���[cb[��eqy7d�um��e��������1��U���x$�t��:��#$C��W;]�cxh�8�F����2���I�UEe���E��
,�~[��$���H�(�r$&�����p
���}M�c}&�\���o�it�*�:\J.<�i�?���|��:DC66!�KT�f[���8)��v�/E�'�1��z�n���%��F��-����t�8�Gc����}�������$�
����M��iw�R�g1I*�J~���e�������� *R����)��<:3��y(��,�I*/����������J�6��L���F�1�p3����""�/D��� �������7#3KTS�_9���6�������(�9e��Uo��<4��`A�sh�3Q4d���?O�%$p��Q��-4��+�����C��D�:��Mo&�|�Fz�
�� �@�_�t���@�d�6x�!G'��hZHdcL����|*���A������������L��^���x
9����p.��E�+j
�{rxo��N��Z��)��6P���$�7��C*���)���L��_�h�|6|6���P��y-���U�Yz�_����S�4��x�GPv��pc�:�������C3�)��E�NxC���run�r�U ���y�]�$�4��(y@��l��������D�>+��Za
h��
0"��7v���X��Q�%�i�LCxK]'u�H��rO��Aea��5��v��P����Wg������,���f�F��>�}����>|@���������E���Y���(��Ro84Gnc���2�y���r	lF;^�3�<4�)��U�V�O5j1�Tt��^�X�
����_^��jg���Um��v('|�;�%pPW��Q�"�hBV�*���bc`4�PJN����EE�HH�p�F��>��/4�������Z��v�{�����M7������qV7�M�V������{�]A���sM(z��h��?�c����W��
��pP/_��=��%���1�P�Q�D7�OF�738$���w&.;�4sy�����%T\��G�l��[F9��M��*%�$�[��R"C�H(X�&.������Z�����%�S�V��G�R���.�j���eKn�_������$mK�[*�i�x �[<��L}������_lNd������R�#9$1F��i,���J5��jI�&z������H^����(���N�H���� ��2h
f���rk�x�Ut�_��.F�5Y�������G���{e�VS����+�o+�Z� �i.�q���������pat�,	�6x71�-B `R��:��{�O:H��<�j:���Z	��u�t��H��(d�n�r�EW��{%^�b��2Q�]J�����o8�������@�[����T��>R��a�H�Ds~z3��m��I�
��y��E���
�����Au���}�_�C@�P��h�J���:���b=������yP���(��V"�\�pz����ByL����i���c�� x��uz�������i�h�Z������h%�DZ���d�a�|=8]iJ�� u���Y3��c�a~�B��	��O68�����;q1�]��b���R��X</o&����1�h�0��Q�{=��`c��y4�G��G���6�_�'����F�]�P^:�'�<�~7^�MVk����Q;�!O�6:F��95�&\�Y��k�h��P�HD)GE��>�[��G�JY<���F�Pr#i��&�7�����������,=6��>G�Y�=v�~3���W"�@����X�:;5N�D�IOr�8on��KM*�]�An�Z�Vk���b�����<0p�,�o7oO`�a��B+n��:�l������${}�o�e|!�Hp��A0�y������l��x��-�� ���.Z��,��@�$����m6��!�<|T��
U�\�
�H����G�W{''�m���ck��Zq�����$����[��:�����HF�@��R�����i���t��E�6j^;��8Ts}'_�]P��+;�EZ�V�]5�Z8�C�n�3P*R���<��B���rI��@6:�H����l����J#V�������l�P���\H#�-
�1A�O|�[���PQ�{����+����k�h2�{��c��F�x�y;���R�1���y��4y��	�������Y���Ao<����5��@�L^\h��V|+'JN��qz�����P��l�T��
���i�l�|�Q���Z�������Ye�w���>Zu�K
�b'�:t%���z�v[�9����F�&G��Q)�[a���)��ZV(g���������A����qs�&�Dp��P"X&���A'Z�<H�'{�����)Kp����:
m���4����z��x51z���C%��&�k�#~�	�:��af�d�gS�����6(w
���Y'�����������z�d��VN+t(����Uq�[����C�El,#/�ET���.b����~���bv.�0��Rz�zT�c0N�XFk�B����B�J�Q�L�,������"�q�M2
���2r
�S��0�V�!���JK�xK��6nO�
�A`
-������pf�(���sQ����r�1�D'G^��3��e�|�ak�8�h��D�1OFcx�\(�#	�V��M�|�&���M�]�L��b�i��{���Dpt*�������������^B'[pN/������3���f�
Fq� ���0j�$a)j����'��*�A�{��];*��%=y<D�2I&L��2��x�������G%���7���O%�Ke%��5�{�j��1��`6T�@�)'l5E��B2��j@P��x]����\�?�f#|���(��7�����L4���������'=����y���Y�R�V%==�����>������b���)��`}K�d�%��J���1������n
�G4�_�H�M	��(Zy��$Nll�P:�t�I��B�.�����G����`���T��z����4lrR� w:y��l����
.�[���U���x�hoL�h�Dy�\x!�0������/�	\��[�0����������Cjn-�b)�?������d�~"!����!��j�7�I���\MF�&a�������Unt�#���[S��o��
E��������l�Q$ b�x���.�:����D��e~����rk��0� d�����D��^���������gY���_3T��������Z����a��
Qv�T��Q���/OF�_5��a��R$\)�5#	X���yS�i�w�l��??�(y�����\,���u4k��e�V&A�$�#����To�5*~�@�Tr�������4H�J���u���m����,��'�ymh�'���N����7��(B������z���o7���!�@y�A-<9��9��z��yH,�N;IA������HC	p��]���<�	��-�#��|��V�W�W.�d�W��.sdk��������A�Lo�u���$���|�5���I�A�s�<��;�����#�	�$<Fd���6�)����&>.�2����h1g�2�Hx�`���Jk�/��j���>X�����e�d��wP�@�]Hp��I���$�4;���C�D��<��{{���i
Q L�����{��>��}���e�J�a� ���
1�i	�Y$����� �+�'\UJF���)'."�c��7�^���I8�x�V9�,�m�q�N!����\����O'm�a�nj[�J�.!w]60l�UM��	!�p�0#�,������I=t���S��������+�`�����N�B��]� ���'N�5	cxH�&�;�E��l��H�g&���c$�7����h�t2���U�������=��]��p�S81Sg�d*���F��'��Zj���}�x����K��C�����6�}"H�����
A��W���m,�	�fn�6�+k�X��d���m.��������$�M���bM����my5�:���h�9'Sp|���
n+kq�4�	�i���&�q�4GH�t���G��LL<�Df�\����5%�s%4?��8r���XQ���d��<$���fv$
4�����?q���#�{�i����Lst�;��-��0	(y��e�.�8Q��h"���9\�!����
6��]�	���F<���M����D��)�iO#�+u$c2]��X%��� p^X����:���g����A�Dcq����������A�t�>���IT[�I�����z�X`v3�H�<���*�&�r5*��B)�_���UL�V���rk���c���c�12� �c���g���?Q��eg�V9��[�o.� �U
'���"�op_���(<�]�M���U������'|�S��.�W�|�f��R����0
�`�EK�Yv&��Y����W0�B�����/"�c����]�/�-��Zz.}��n<��G*9v����i}
�2A��m�l���,\�X `���#o��(P���6C����[4zp�
������R�k�$�����l���Y��r/a��]�2,M��J�`�;(c�!9Rw�|5��/y��`���T�\/�V�1�(��k�#��?w�\�B
@v����-��2���n��2��^BO2D�7�$��������2��d��AMVa���f��/�r��6�b�j����J�+h�E]v����������:���-{pwj	\
�mHC�Xc�;�S�O�&��F0^GB��t�<�k��K(�#�j���Um��r2���d?_��B��E(/����rIo���?�#y��H7s���aV��>O��U��p%�)n����Gn�������n!�f��	8�{�C#��(WW�8��N�����'���\���}/6�8X��YJ��H��h��z9�l��0� "��Rbd~S7�Jq�I���L��H���z�"CN�0.��wA�����H����_ u}.4��Bx'_
��:����n��nK��I��VZr��za�Yc�0Wy�k�'r�~O�a7�~�	��^	O�rf2��#\��u���iGd]d����8?���<������5�W�,N�a�����P
I7�`)�5`r�I��P�\����\(�)�*�@KV��n�w���$���j7j�9�����U<w���T��s��U@(�'�����hX�����F����8��E���Z;�f�9�R������=>c>��8�H��P���%p:qm��	E��t�F�_�K�1�OKR�������d�x�����B�k�.[����r�n�}��#Y�'����;#4�����A�	�(����� g��`���{�x���������k#��"��F�`9�S���	��PY������r:{�Lm4���������29���4�RW�Q���j���������J�3�_� ���V��n���<}�|������0���>��	o�T��0�yXU3�S��Q\a��%R���.���n�]����m3�Z?�g�%�F��Z���JC�R%�8N�4�����'a=�!�hjr+��	�*���_�;�����v�=��,�����Uq�S��F�{Bb=/�u
y7�SR��c0��|!�����`[�R��0j�l��c��	\C��:��:��<�[�7�������� xv����B����u\s!�yN/
;T����o�e]�1vy���pA�X�K~�pM�Jh:����A;��T]0����H�#���e�g.gL?r�+s����d
?O��i[+�����A������F�
��^�w9�>�����y�]tO�d�W�xT:�R)���{�$�U�Os��WV��a��� ��j�3@��7�{'Po_�����+�J��Z��Ob��/;{���o�)%���X����k�Be����E��oZ��7���wK��
>J��B�*�M��(X�Pl<�F�x��\+)�L��s\����TE�Jxt�z@�	T���Ji����z����������p#���{�5�f��C���1fKF���kb�RPk�U���N��O����X	��
h����o�0���KPzx:��\g�h����6T�Y4C���h�~w�,�Y����z:w&'[Ugg@�A!��8����c�-vvk�Ba��[��.5��}�v��M_��c�v��D�������<=�)�1)6�#�B�q����-��Y�����������!������K�]�������s�G��je��%zmN��r�o
.7��J��9��O+�|�'yg��������}8�d��"oM��Y�Axo���]�q�T�(���Ba0��k�e��4��PN!��Xd������L��L9m�_�Y�Q�"�����J@�!."#�w
�c������9�c���$5��*�K%��O>��N
��f����x�;Ao�jQ��A��voN��:��������?�
�T���*��L�HF��9@���wH����(���t[k�^]�������>���kJ���:�H�PPE
<p�b����.�9;������o����="�Y�K��,"~���h�����{V!��,���#��
��&��n����[]{4��
�<���FMh_�0�"D�U���2R�4D�C=��:����A�D���i7�Tv1�-��@<��}��U�����6tP}�_��)x�"�p��
���l��������2��W��m5/����;�j��1\��/�a�!;T�EU��4�����o��i?��G������Y��y��Qu����b�N���y�Mz����=j����?G�����(����ln��=]�^�&�o��^qw�<,����ZYJ��-$^�VT���k�
���a9����7�����Zq��}�ZAW�5�r8�i'�Lp�����[���S\{��oS�<�9H�f�+��P��$�y��sw7�Fm`������w8��7'ji����f���:pN��
F%���v�*�2M����fd��uutR��SU����bBe�����@��s�� �x�Ctx5F��u	���N;vf�5=�@m9Dn������pOg��j�'F�?Z\����tf����k�?��f��$`#���'�2�S��!@T�1��	�7{aZ����
J����d:��[�N{_�;k���%��Q�l�b5[�����2�5[D�����<B;�0��mo�/�v1V�`�r������}�fu`��-U+�)U��|%��'��.+�Z9��2CO_L�_���1�fp�.��LO	�p>�/=N��[�||�=�.��U���!��M�^���������\���j����D���\��t	��1�a�1� �k������s����Z]&,�^1PO����������t1r>������U[k0������h8��[���b�L��*����/�z�J�^L����}-^�ttL��%gO�?6~y�jg)�Q����L>F���Q��{z���������F�����I�����7���j�
K�m�XM�H���*����o�n��n�4�����-�-�U;DY�=��3���m;.k��h�����vCN����J5�c�_��Ct�!t�������l��Ys</zc��O���3S������/g
�k�r ��~X�R��UIr�����X�����e������5/P���j�^)���R,�<S��l���}���5��Q�X�����#l�)nQ���*���-����X���u��<���#�z�'s�{������G��g����
������(�I���2��5��+��������ni�k%����\���U�U+&����1
���3�- 1p�
q�����v0��l��@����.�^�r7q���B�5����_�2{z���s��
K���%P�]��Ua��w�?}���H$��h"Q��1�8���4�G'�����o"&����5���s1,���A�PTv�^
��5���W�^I����X
�m
{���d���r�6N��������K�Y(�����UH�ro`��,�.q����P����X��
h�@�0bo0]�A�&n�r
d����@O*��c{���+-����=^��MnkI��i@�"�.��Z)�S�����$��1�J�%x��@���h����I4����6^���	}���3w��k��m!�����2A~Ld��c�,�Vx[�VXyJ��%�U�F,��{!���3�r�
�I+���^;����rAZ*�y��
J�!��L�O�}�0jV�z�-�@�4O���No���{�%�c����G�bI|�M
m�u1�
�����4����n5�B,���u���v��yQ��E��Ba��7��
]���
~�}-�����Y��M��
�<u��A8�u����BIk�b���_���~�z�o"���ulv���l��W7� � @�C�|��9���F�U�������f&����^m*]l�������>���wA���:$ 
�|�������f�Gck�&0��������bNo6�7_��T�Uo#~D��~=|�D���d3��Ij+exs�L��1��@�m��J����^����:q�xp|���+�^���n�?p���5�}x���=��n����r ����`���Z$�.�[�����Hf���+��`w��� �lU��?9���c
`_64
�N���[��[�������pz��,�
�LG?4�~Y"���;�)���&�`f,g�E�R4���M�@D�T_��hR�>.�����Ao�G�Uv ?P����,?/��R�}��GYN6Q~������2��l<��\�~�4������F[���<���*�(,�-?���Y>.4Xx=7hQ:�|�
��&-�kb���r<]��0O��cCr�#Z������'��+��1�h�b9@$f����/�|�<3D�rPCm4���'���-�zNW~,�O�������}��	�{$�J%�x�B^��S
���������y�C$��b�"+#M�����M]�d/kA&pEl/��4yBJ*U&�!�P�/Dag��O<m�8��7v�*-NJmr���}-GB�y��6��ES~a�1S��x1�#��W�>=������&�����5����V�|$����A�s�)��rQ�!���Ac�Z�z~����7}��}�'�'�	{?���XY���0�-����[Y��oU�F9��\b�@k���.�,�����o�\����o)Yk���K��R���&�oA@�ri
]�O�n	���[�Y����Ph���GbY��w(���`%/��6^�^-����~����?��;������~z�%�\��UG�7��c��}��p�v���O�#�����8k��_9	~
���)�9 \�N�����f�i�Bb��������n/��++���3@�����sY�_�Gbf����C^���a2�B�?o�X�/��Wv���g�0��U='n�� ��a.��~X���m!�6�R�~���g�p
;��9�h)�������������m�	�n�/��+���!\�N���B��Y�O~���Gb�[A8��K�m��~��;�	�[t���	�����2���eo�X/��+��g��.vB�-����W�[�~!��O�#��� k�%��q���3@x;���)a���O�#�,?*��"�s��f�;��K��+?��@���P*jc)�-����2��t?�LH,�vg��t�&����>>�J�k�����a��jL�����3��;A�m��5��>4����������>��y��
QGn4��/p?5/�C
�[z3����N�I����EX�M�MJ�}���$�;��'�&.�&$e�b���z���z%�+���y�y�QI�@,{�
?g��<IQ����_^Y

�S����b���e��~*?�}+1�����Jo�Po+U,�i`�����������P�gU���|�^C4�A!x�*����0���/�Z%����0�
�pe�v	VR�Z(��P�S������C+��&���v��P���	��P:*�Y��#<�`
<�2�����
�tp^�`�����rBrS��I�7�:���E���_�-j��d��Z����u������G���4]F3�����%N�x�94Jo����J�^��O�����F��3��J���h�H����a(%�~������1��2z^_����d�Kn�x
��ld2�Q�pi��6��#���+����<�*�J*��-h,�>��}�����uz�$sM���������tW�\�l���p�b>A��I9	�/�F� 6��v�l?��O���-!�2��L�$����s��W���s�eo���~�3�l�����$�����Y���S�=j�a�z�$/~j��ou��vw����6���/�M@���������O�l�������/k�I���<a�,�[B�i�n�zj���}OH��'C���T2I �E&�!�HO���}��/m����1 ^�%��bX�%����1$;�
=��',���������A_&����7�;��!��~`����#��k���Y|�]H\�$�	����Dmi��i��, &["[Q���+$�Z*�J`���VO�Ju�S@���hi�$)Ap���B)��,���IN@�`7���r^5�}/�����o2V+(��� PS�b�'�6?�q��IF�q��}������2��Y�����D��P[�]-�.�6�9�9�,DA��}�����e��A��w��K$h�4�2<�zV����P��%-sI�`4���S�.+����0`���i����������`3mX��=0���p�q�����S�Fu��7��P�q��������
�|���&��A(�1�b^L����;���d*:�<y��'�VX>��di�#�q�����s��u	�Tv�]��Z��d$�
�%�W���)����)�s��V=��MrBb�R���:R�)��N���t�(�J������e��J�P��8Vs�������� �]�v�\8\���D�[����j�����v��������}/"�p{�C�;�]����;��
�{���^��$��>F���7���w�eE��r��J?������!FD,��eI�����r�����i}��`AHdX�~c�d���-���c���E�����s��=��3CoJA�f��j���4������%
��j_+|�n	��_Kg�����@�X	�D-���
\c;5�[�������\dO}�8�~�ei\���i��>r�-���-�PJl�P���Q����o/_�L�|�[�����EE�+��L����8u����_�*��B`l#	P��<�fbB� ����E4��	(���h�����EA��i��6�^/-��0F&��^s���
�Gh5A6�Xw��?�d��}rh�/��������bV�(&�������'riu���X]��������G����hg�pE��+�����R�RP�S���e�P�W��t�����Kv���dK%� �o�����% ���q��9�����C�w����i�zZPsM �i��.�yV�r5'���Y��{��[O�J00����R����k�~���^�5����>�<~"��g�w��3/���{�}���?e�}������g���@��e|'��2@{����o��GN�)%e���+%g���*�V	
&d����!]"B^�^�k�Y)���Y5����'d���*v�?����Z��,g���u�A7�����`�����,�(	���Zad���&g�)'�0!�bg�W9a�	Y��,g��UdU��RT�\I^�eY�E	dU�����&���UM�r�
�7�UM�JiP�7[+��R�:v��l.S&��wh?AW!^G������R�:��K���V�+Is�8+��H��Z���8I�����|�C��m�N�v=^s�A���@��$���Y����F�^���z2w��X���<��X�����}��d�H��{Y:�{�}�ibT����F?����N_�f^�E���Rm�L��G�.�iH�>(%�[9�P���h7N��g�s�?.�6>����/$]}}=��v�dC���w@n
��(�(97����8��D�_�#�
�����$t���7�����	�j�~��_d/��c,	��}8�,���s>]LH��91:����Y�5�}���Mc�(�A������*��v��y��kV9�����YL������,[?���E�2���wBt����a�����>m�`x^2���G�&!�H������ �������^���~��G��#A����t�[4���qo2����leB�3��k���R��VE���Q��+sK�"3�}�����-�r9�zQ)^��������V����3&X�C��=����8�����Q����(������F0��������T,����^�P����a}����B}o�*�,|�ww������[4�P| hu�X<�P@������;P�'���i��|�X6_��|�f�_���������F�y��<�~tz`��Y�9���_��/�	?�{���3F
����$�IN
��M��6R}+�?�$h����>��VK����}F+�?���2��Sl{�#�����o�����6�mdq��
+k��g��������5��*���������E�^U���d��t����>���t��_��r��������������_Yg�4�W�k��=�j��x���T0&���$�k}^���biV���VJ���P��)���Z@u#�Ki#��k�J��|]l�g�
���<�g�Yo6���\�$L�,��%8_����A=O����D���sz��_��>������	��:�����@M.�&�)�v:����/���r�Xy>�-�>�'�BI�]�D~���,��,z$�����#����^Y�)%aG�������T�hY)0��O�N�a����b�_OF�EG���	����X%I�xP.���|"�
0003-JSON_TABLE-PLAN-DEFAULT-clause-v45.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v45.patch.gzDownload
0004-JSON_TABLE-PLAN-clause-v45.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v45.patch.gzDownload
#42David Steele
david@pgmasters.net
In reply to: Nikita Glukhov (#41)
Re: SQL/JSON: JSON_TABLE

On 1/20/21 8:42 PM, Nikita Glukhov wrote:

Thank you for review.

Attached 45th version of the patches. "SQL/JSON functions" patch corresponds to
v52 patch set posted in the separate thread.

Another rebase needed (http://cfbot.cputube.org/patch_32_2902.log),
marked Waiting on Author.

I can see that Álvaro suggested that the patch be split up so it can be
reviewed and committed in pieces. It looks like you've done that to some
extent, but I wonder if more can be done. In particular, it looks like
that first patch could be broken up -- at lot.

Regards,
--
-David
david@pgmasters.net

#43Andrew Dunstan
andrew@dunslane.net
In reply to: David Steele (#42)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 3/25/21 8:10 AM, David Steele wrote:

On 1/20/21 8:42 PM, Nikita Glukhov wrote:

Thank you for review.

Attached 45th version of the patches. "SQL/JSON functions" patch
corresponds to
v52 patch set posted in the separate thread.

Another rebase needed (http://cfbot.cputube.org/patch_32_2902.log),
marked Waiting on Author.

I can see that Álvaro suggested that the patch be split up so it can
be reviewed and committed in pieces. It looks like you've done that to
some extent, but I wonder if more can be done. In particular, it looks
like that first patch could be broken up -- at lot.

I've rebased this. Note that the large first patch is just the
accumulated patches from the 'SQL/JSON functions' thread, and should be
reviewed there. Only patches 2 thru 4 should be reviewed here. In fact
there are no changes at all in those patches from the previous set other
than a little patch fuzz. The only substantial changes are in patch 1,
which had bitrotted. However, I'm posting a new series to keep the
numbering in sync.

If the cfbot is happy I will set back to 'Needs review'

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0002-JSON_TABLE-v46.patch.gzapplication/gzip; name=0002-JSON_TABLE-v46.patch.gzDownload
��@^`0002-JSON_TABLE-v46.patch�<kw�6���_���md���3���-��:�+�Is����H�bL�*A��m���� A���:���S7�%3��x��9��j��}�j4�����lY->��w���f����{�������j�C���Z}������������,�Y��'�{��+>��7N�����-��.{k���Qg���V��Vg�Z�V��������?�����Y���{��^���.:�ry�U*����f���p?9�*6c�3��`�
�vU�������b���'���3k6k�h�l0Z����L&����OS�r}�lc-V,g��'n�Q����i��puV\v�G<��V?X>�8|`
=~��J�Fs�`r:CQ�E�n�-
FB��b�[�3��p��l����%pA-#���Bn9�p��/�M�P������#�����+P�����2�B����6�r.4���=+|�`TmA�8���r����gEn�5qdr\d��<Z���`q�z�j9Q�����o�p3��j�f�1�)S<a�q��0}�l(#e�����9�9�QmKS��R�)�N>�j	,��������)�p��<wJ7w�+�\B3�����x5�T�Vg�tYFA�aw}Bw5�M��G���.� �P0{l���)A:�m2�r�\E��Ub�s����������F�\�u#fA������O�_
��}b�|��o6Z�������=j6�ck����/�e��O���O��l6j%�!���\{O 7����B��}d�	A�]���m4��
��������$�0��g���%+�7�����`Ei_]���~����/�oT�����H`��l��l��a��bpA��eB���P��_vo%�8��{���.���lpC��[���O������`.��-�u`�{���Ri�������md-m	iPKn��������a�AZ�Y��q"X��F���9�\���/�/7I���e
��<�m�(c,����_�;�GU}
?�w��� K}�{"�������-�����u�!���CE�"9�,9�yr�+~t��;x.m��HA��+A�4J�f"I���:xG�*���uD����E��U�A
���L��0�X���������%7��#1���p|Kga�zr(�m��1R�
���j�)e��?
��]v,;
��3��������k�{�/�sP`�scB�������^�F����f|F�N��o/���A� C
�ru=� �MC�7��r����(����8���>�y��:�+g5AJ�7G�&s��cJ��O�R���������G��r����������*�N�������e�.�c�/�;�<��h��{��sb�����[��t:W0i�����r�t����%���/�=���H1���^�������i��}}1��u�����w�^
>|����L��lSg���� ���P�L��2��I~�������}��s�Ok��D|C��z����Aj�z��s�������\v�_>��e�?���y�#��$�<�����W��E�Q#��������>PiS5j�(Ua&�UU�)v�N�PtM��d��#]�e
��"����.��G��lB����s���H-�a*"
�9����-�������{�?��������|6���m���X�0���g������l*�CH�{3��JN�
w�7r�u��unZ�2��������w.���qI���x7��"��y�
������2I9w�i�V�d�D�����E|�B���fi��ap�p�t��J8xp=�k
	n("*��k�9�3XUz��6�
e�����*��:��R%��fVD�D��y��{�4c&xxo�'MIqhs)j���$���s�9S[��9uLLA���>T��X��M�ZdMI��E�C]0��\_�h4�����dC��J�D�Q��6T�0#����]�gJ3��`@H
����KF.%md�*Qp��@��8�����;'��Ps�m����In*�\�-vCd�kL������H
����JH��3�h�hT�@/���H@���C�������R�'Q�1��*�H��8l1��z	*�? �5:o�R���NC,h�l��R~������8�oK��`:
����BB�@��i�r���T'kF;�������8���'��������R�j��Q%l��	�Dll�s��m��3�c����!(�[�� to]&��8������qb�]O6'W�t_��)�@��M���P'W2��2`(e6�([�CX��dx	@!������0�l�O�Q�#|���������siJN����z����H	Av��?���@����gX��5������M5����
�j��	�T� ��5�����zvq��"C��U��Jb�N��(�-�9������7���T��%�=Y��0�����82�S��*�&8��FX'���8���X��l>���Zu�Y?j&'�P�E�A��-&�rz�[W%� EM�1D�P�$'�@!���<�yTgHp�
���5���0H�NY��IJcmb�4SZ.�D�A�HIQ�n�4���
.(�X�eU��Jr[�+�>(�����^�B5-0�%����d9�Q�T����|��������%��G-$�"C������s6u$�a��Q��%�|�H%��l9X�B���M���N	f!�S��PC;$��J��Q��D���:�DgY�nV�+�����+���J��H8�TF��CK���.h��YI5�� ����:��%�s�'�sN����:�o����&��]��Y�GRhK�s�l�JTNb��cFA�(j"Y1�\2
��~6	�D��D�m2u��2�Q�y��+f~d}b*��,��G�|�1];����O1�s�z���=>�"AI�
]��`�����9���&�,F������i/�����r9@�D����
�����(r5�AmW���I��e��D=�H�,������r������,gBH��[e�A�e"=����<�vEv}LI
G&���aa�0���d$I+K���1���d)�����xn�b��1���c�\����G��� =�e$��cr{DU���Z1P�
O�*\���hn(��ah�J&q`��@���U.�:b].�4B�f%��r����b��ug\�IT?/2�0�=3
�t,�1Z��n����@����U�
!�I&�p0�A���zJ��(�-��P���>�L�b^9�VLAb�<�(�\0������������+��u�J�]���GI�o~����j_C��ia����
w����~
27���W��+�������f�dQ'?�>!C-����\P������NbK�'���(Wu��G��H��$�K[�/�*:���9Y"	�_�����9�i���N��B��{��;����L\��4{���
��<Ih����F�ay�d��U����H����s�d���i�� ��_	�kt�!3��z!�{��A9nVP��S��Y[�O���;��o��k�Ey�r�[��:;zC�\��������A!�M���x8}@%�@����0��P�r�M6S�S������MW
�,~^�X\1N�OK�gD�z��r	z�WV-e/�R"�p������Z�j�=���<��>�9S=�5lZ"������NRO�u��pi\mG�}���8vGh�g�^R}@���|���F�,�&]�>�>�BK.���Y{l���9FVd��2H�j7^�So����J@vc�S"E�q=N���F�d}�'��������~<��x��wSR>�-�2h�c��z����G+X�zy��#�����%=�9\�+�q���������5�t�)m��S�K]2��|�U,�������G��Ot�N����v'R\r�-�x2��3n0Sz1�1I#����K�A,]W���<�Q�I������X��"�yb�d�l w�P�=p��{�T��#>���7Rn�e���<��i�0�����GP���UF�}�6�?���<��D�������w..@r�u �+��M�A�8wj&����K�u�Nx���W�omma��1z�Q,���?��G.�a����H9NI���&%O������������|�O���3{p��y���tw�B~�kL���?�|����^T���+1��3�h{#�����c;������q��`C��OU�&�9�����X�����;f�����b���@X���C�j�v�kce����b��L�4�[����7uWPgi����i5�V�2���vvk�;���+�3�+����F��������v���E�����)c.�%vN�FJz�:����#���4v2�!�i�)a��������K�td48��<�z�Q��������l�����M����M�����<<�������g��_�^����S�C�����V���r���E��Av��K g�E�,��2��R��{S�p�e9����wP��V*������G
g���aZ4��Qh;����&��{�v�}���q����}��P�<�.O�?��Z���IV@�����S�h��9z	�		@�s�����j{���2�R�����6��0j{<�8�<�3w�����pjE�d��2w]����!����O���Bz�2��N����N�R����N�Us_`	�5L!�1��A���x��'�R�d'J�Z%f�a�z)��Wy�:?���w{7���%����C�m�mZ���h�7��E�d���d���,����V��"wW������}I|�F���F�0&��Kf���%_��~�Z������z��{�6S;�1+3����q�Q[I�*"k{��!�1���2�Rb?�,�i�+���H2%��z�B5������GJ|�Q#��i�-���xA�!
x�^��A^�����mS�7�m��5���d>�J��1�g>lB�31���d9;���o^���>�Ezi	L������7��~!�%���j@)�fC��U{���|��AV';����
�`��;M;�~_H?	��{����?
�O��"ZGF�������F�^{*ok������6=�����}�*�%2�G��,�����tO�,���:���N�P�X��ih�[i�/�X��O���M������&H��^�R��R�R��$��Q5��G����/���#����S��%�������{���p���E��@�N0�p�(A����c����$[�T��1�4��'�yw��D������!�lZeQ��������m+Ksx1����b��GV�E2?p/�-�"~�m�������XIA��.S���f�}�k��`��,��.�^��$�U�@��u�,�C/��kN�^�Fky(���S��O�>�
�?�����0��@#2�4����^����]�z�a��c2�Y�����+�3����������nBg���=:�u�Z���n�d	��u
�oI��K2�bQ�G�uK�
NU�BT����3d/)H�9~�+�CP����0����[2���vq�/iv�<e<�t~�����G�M�8��P����G���%���s�%�B�d�b�,�����m��m~��1���������`���l{^`�y�B�	-�TZ����l�1V��I���N�����p-�AV�J��R��r�B��g%��1������4
_�c.��nR4�n��O��WLG��3OO�Y!�p����#e�����Q���V%aR
�)I��
!9j]EMJ��
*�%)k��w��k����/.��;�[j8&���-l�3D������3�vsk�^������g�I����$���'L�u-1J�Y���t}���JhhD�"K�o������G� ����}i{I��g�+���m��F��=�e�fZZ������S@!c#�������W^UY���~�����GFF���_W�Y�G��'p�F�"���X�R:iMz�g��Nj��2k@D�rsZ+O��s��v��3Y�(K�I�>��a}����K`�8�[8A���=".�����M�>BM�9�X@���/���3��Y�{�4��B��D;���g�����?��L��pf0�V����3L����Xo��+Eo&0z���'�q�H�OzW/:������j�[���fS����s�nL�����Rj!W���6k����DQ����4������O��d`(|�`4K,3l�#�}�)>&�A��x>	tre��V�R�{;��J����q'�h���<x���[-GJ�Nf�C���,�q8qh}�d/���v
�83	9N��O��AQ�e����u���=�r�+�Bh��^�a�'���7�%�v�Z��������x��\4(��n��R�i&"��n?��%�.I������@'L^/�Z>�������K�u��~P�E
�`^��������<���U"	K+3L���N�,pZS����^x�%#
(p��_��0��pY��n��sn���F��F��hU���	�,�������B��JnET������n�V�z����tP�5k��S3�����$A����5�H�8�l������@��9��2����^�Z��������I�lu�A��xb�p��DQ���v�����,l�*�V�4�Mg�v�9��z�4��$;����;�`�J�;^�0����aX�Ic�[9J����4����F��11���_\v�Lf�K����l��N����r�RC��R�5L�`B��|�����-��c��H���";��D;��Y�����o�<�5!q�61��I��2xs�B�|s4T:	G�P{�����8���=��Y����&��dgL�"���$E�������v�n�e�&���������j
��Z��,V����M�H�6���^S������x'�L�O�h*�~1�J��d�_G��x=>�a�}�f�r�j�gQ���j�ZkV��w�'��4�d�!!�^a��$�(�F�u�>����:o[([���TJq��[ghQ)�
_�#mu�����}�����%C&Tx���^m�F��EOb�7w��V�)�xy��������8^�C,�N�u��J��9q��e@����{�R�2Y�_u������%cma�$�f�F�������1��^��?%����������9&��Q��m����V����pg���`���	Nk��KiT�f7!���x�9A���_Z����J�����]��������/�����$1�8~�;qF� ?_n�W�5]d�E����
��;�M�:���J����R�Q�5�a�eX�&�I;��"�v���[��E(a�n������f��0������+�e��\v���@�\�{��EL�(�&���a5��7|�F�H��d�r�F�rKL��l��~�b���|����+�\ S�H����A;�4��KdH�%.O��ayj�b��@�d���M�����(�DdO���n��az�I�#uM�{��<����OO�W	6��k�&zK��e�0c�.�����������fNX4�%��2�[�#����;8{����!,�}^����'U�pbb!g5~�<i����#95�M�:^G��2N.
�6�v���or�X��*�6�J��nv0P�������+�j��l�J�f�<���0�;���N����F�O&�`���Y��-�k��<���|��j��=	�M�[�<C���.�j���K�����H��$I��0����$O�C�(?��[���2���^���J�M������ ��3@=�_t�qJ�v�����Mn��O���� P#]M/b����'G���9:�#�����}V��e�)>M&���+9���f�A���X|}z�Ro�M.�N��(�YuF��)�*��G8SQyA��D���8�wg�}��bPi2[t�M���f'��*�0i-�/���}���Y�_Y�;�8���|�
�*iC0�~�S�V����T*A���Y�Q<"�8+WGc:��vuV��9
g�i�YI'�V�d#^�4`$UE$�?��@�w��^�K+�7>)�(�'&I��3�C�9	���m���R�.(J�l��8OT��U(�S�`�5iVO�Yk'��T�I>B�Y�+��?�t�#�2x=P�#^����hM�y~m��l)�J(2v��%\�\`)�*G��-�(��^G��]q�3���.G.vK�t��yK�H�#����32�l��Ij��z/�S����S��v��{i`	"�yzx,Eq�F�r����lXr*��DV|5<�z4�$��a'���!��]*�:jWIY����c�d�z��#��*�i�3��I�c@4sf������dE�~U�]��`�T���<l��;P�t����A�U�9w����G�t���(�q(#�Oo�mT-b��2�;����0����I����0,�DJ��,=�-l���Ayb)���z�����!��`�;����9~���W�����7��(�Ho(��H���&��^pLL����9���]fZ���������y8��w��y�?������bk�*���������&����T��V��|Z����i�d�K�B�'�U�}
?��/�W���w���Uwt�_$�S�sq���_u�����K���J@X��r��g�`.����?���gg��S��w��;|��]l������������n�)�(�v@T�_�������7�A�w���]��f|��a
�2���3���m���w�4������&�a�.��?0
�3��r���9�^����A�)����������y�<�/���q���tQ�b���kApy�9�����0���������%�n�m.�]��Rk�=����[o(i���.~A��	Mz/:j`������y�9 ���

��]����:/���O`���>i��������Z`z���r�fi5���x�y����^��:>���m�vM�i�A��M�{�����C�  9"�O5O,m��R�5��k���\��D�����L1��jb,^�P1x_^�������W����,
N
:�����z<�_^-|y���K����,t~�6�O�h�����A��;�\�er�w���������Yy\+��(����K��=?dTa�V�����������?��"�
z�C�z���:6Qsf��`u�L>Z!���]�S�7j�n9���RVE���yg����~U|�J��V�X!���f��T�9�E0���@���c~�?�d���+�����]�>�X�t�R�W`��l�8/������a��u���������a�LU���!W]�`��w��|�aU�������8��0��Y�f����v�9��H	L��t-������x�4�u�M�=����
��h��2�����`p�b�W�t��%�Z�U���c��� "4&��{GA�al�@��|IKb)+U�RSiT�59�R�J�?�{\]����y�H`�t�����I���=pq���n��8
RE=���8����G����g8|��,]N���H^��pPcL��
��|<'���nR��F���%��+E��� K��)\()���I��o�[��1z�d�����c���������"Y2"xXx�zx,S_�Q����R�Kg����S����	��-�����������?s��Iw�P`�*������`�D��^�U���JDi�������!���3K���K����3�V�wF��d�;s����L*9�T=hp�F24��7��9��8b*U\��&��Z��^DS6�~j���������l������*&�
�|�}�����������}��Q�u���7�iz�2�`����������+�N�K�tFy�0>� �#��4�����{qf~W�A	��@f����T����g����h,I<�SL��u����/���&�)�SS�o��i�;�D��h�������c���I
�N��rn���8[`�O��apu��3�*�����uFj�6�;��^�8n�zTC;��]�y9�'�7�N�3q�GE2���Nsn��5�1)�q�Qe�m��T���7��
����N$��}��[�Q�~n�^H��
?�h�d4N��~0'���������sx�=S��~�B9�o������#*W�
j�B��wd������G�hD�FKR7�LEB;p�g���d��&Dm�;'�����0�,S���.bx�=�����V�K�1��r$��-��!8"�#�0j���SKGX���h��{U�
�A�����4���`]����$�9�f�!��L�������G~]���W���~e������k���+�����]-���������\�&=���f,������]����p���D��l���.,4�\��b�T��YuR�����hT�Rr�J	���P�I.ex���S�"�c�p��8Z��
�o���54��6������Y�����_xE�xtRV�Q����xtf�Kb�.:����IqSvo�;b:;�&�fT-���hZm�&��N��X[��u�rd����C���t1��\D��K�*�o���[$8\ogh��WE� 8<$�3�s�e�c��v�y��`��]r�����t<ab���NX��I��+2��tH���j��J���"��;�g��
�rG�[����=�[o������`���n���$��X���y�����m:�e�dv��H���ct�ex��+�j,��1������2����A4�U���
�#'��ao��'�������q�r��:���H���Ag��4����p�������Y\M+a.����X�������<W";F�\��J�l�J'�:z�/�N�<U��`�R�T�� -����z;�J{��"IV�f �"#��H�b��!$�PA;���E�#�s�����K�G�(Gp���	�w6����`"p����<�S��!Qn��sp�a�N��m
�p�_j��N�l�Y_o4��D\��J�G�0���m��������d�~��,�hV1���+�{�T����Y���	ss���u���LF��5����������_��������-���W�_��������$���Z����4�%fBt��o�^��u���r�����Z ��%��9~L6v��C�9���iSd��:P"�&*|���Y���V� ���^
�`w�`zM=t\Q���BZ�m�_<�J�,~K�x|�EQ�]7_^^�W��f�I�/��S�
�F�����kv�����P��S��_�
j�������
Fw���m�fe�nSJ��$,W�'��<.���z�6nD��=i����VI���M�O��dJN����bTH@�L�����M�%�����0?�����5���W�
�f��d+����Q�/b=����Xf���j�B���'j�4��:�&u�df��������f=�vVjK!���H�����q����J�j�R����Z�WB[;0H�c�i�K�$C�g���5*��/k.l�=(��5��f"��_U4<�"�@��	�Qj���<�
/�R��F|n�����E�x�t�cq�0�Gb�R�����o7�Q{�P�a�yR�`���K.`zYRT`���o�BaK�h p|��������~b�MS��������c����?��K�L'��Q<��qP��ZG�������0+��)t*J��c�&�����wo���%��	��������`���[o.����!�������
��`1�V��E���,��ed�"��,Z,���'
g���O��z0��0bRv��ddAi�<#��:�H2�4���V�x5�t���S��{K6aO8����k�9���u��a�:UC�)��bDB����B����4��@����v��P���
8LaJ$FC���Z��m.�V2�-�eW�qj8�.'���'��������C�n�w�t��e������&�������[�v�8�����
����;������|3�Z<-@\T���{��'��|��vgo�����[�����\�^t���r��I�Q=i���4��x��7��|�#��#�����������5cD4��������jk!�\0~N����/�����"�C=!W?��0���x����������\��
p�6�Cj�3�D�M��>n�J1���>����������r��si�Q���%{����F�L�w3����t������z�':N�S�X�
�bvL���V
�@���	�3���E[�������9�	�|C����"
�y��9|�aa
/Y�����Z�)��Atvj�G���[��n�H�p��Mq�?p�'Re�'�����"����������<�|��!���w��pQ)}���	��Vz�,M�n]��"O��Z��
��/�u�4�����)=�<�W�eB�9t�{�N�,��@%/����c>��a����+x	��0Z�P������{�x����C��9�FPe����%���&1Z��n��Hn���G8|;~���E�%�e�Fd���l?����9����lk�	j�b�E
8,�8�R;a��]E\X����V���Z�A�h.��K\��$��P��x)�l�PGp�
���	��
�Mp��@L�����M��0JAw�~g<�����'S�����|���"�-������/D�[����hO�F��6, ��&��<u���d��U�5�,���9�y~��p�@�%�"�����{Pf:Nws)+C*�0�������"�Q�����(����Fc|���k	�����S0��m����a/����d�]����3[����t��Y'�U_�g��P��E����
�h����~��$��qI@��k�b����R�ub6^(:s�;S���8�n8Q"��CU�@��>�����9Q��������Y�#iV<�hR�V�"��c\
Z�\��A��c��,lvq��s36r�v�����?!���v
�������wU����������]�E`��O2��������R�o`�Y���n_���������J	=z��Z���8!<b��<���sW��
�h���hX���u10�V�!�w�jio����$`?� 0�v@@�'6�93i�?��������r�1��'GQ��3N�e���(s�([� �D�0=�{6_�m���("�
*mr�^M��m�w��&��c,�e��nRi�(������N8�z�%�^��v�����n�|�t�hng��3�&
9�[J%@7��*��q����G~�BE�N�����]���s��T���Qn	�cZ;*��e�k:D�3IgL��2��M ��b�	���r����P2�������\X�D����[��,��!�zF��o��b6_o����
��S�������e�(����
�s���i��5������~����
?�vJ� �P����������*���R~���Pa�����m�n��*����M6#+��UN�_m�5\��y���)��,k������� ��-����a��f%�>� �8Nvi�>g��m��X�����95����_�~����n|@S�[�QN�������6��2�zy$.({���k/�@������/�2\���Waf�(��3t��������`6��9��R�Kx�qt=_���jF	d�H��tR�A[�ZC���
`���?���R):���%��/����`�=����bC������N0��Zf��N=��m����T��8U��Y�2@]im�����,��:�z�q.w�n���1�t��5����Q|�X%e/��rB3�/��F(�r<D���0�|��j�,���K_5��Y�R,���kI�Tc��?��~���>6��N��b��n�uoC-���	��&Zo�?$GP�w+�0���>�f@F
d���=Qe+*e������jB�M���C����w�`j�����N����w��(F��K9��z�'��dS�B���,������GV���.����tu�6��]�-A
h�}$��_�?�7QL��!�7����;.�*5��\Q�����������?���}��������������c+�9$%V��wc$%eR{��&g9t�.�v����cE|0�������_����C:���".3��x�����@d5��W�gle�5N.�+j��<�>������e�2.�;�Ubr�S\Pv�U���f[Ai��w��
����B�1[6�h�6wc,����>�������i:��
�N�*�u|�F��"����)�J�H�f.��e@xl3������1)g�,�>����M?��9D������u�&��6k�c�ZS�j_nw������a�j��L�0Fz��P�{ql��3?��nP�jE��8��]�~���Ir�i����T������n�J��8�qf�)h�9��u����B���A���c5�w���
�hY>�~���\N]W�{�9Kq�����:3X�3m�
�Tl�}j���3|���S�X��89�*$��v�	�<`*G�iC����:��WV[�����C�����14��-��������0�y|�kb���\��w��m Mo�p���7��`������8j��<x����y6a=��XV5>6��tb���2��������OS*9WQ��c=��G�������M����>-
��m���)1�O�2���oGgwW�i����LL��s��HO�(��4�
JYaXd^PS���!"���9\Y 5~���X�����tw#>���W���J*C��������:�����m=@�D�'���
=d\gY��b}w�!��y,I�56sCTt����N�S�g��u�Vuc��9��y+��[Dl^����*#���Y������RiE�z�<�f�������.Go
O8l���@�h�
=�,�+�&��&�$+H���:���������R����h�d\E����]���g��,{;��j�v���dn���=�E���c���3�K��zK�w���E���p�A���a� O��&/��[)z#��8��2��8:)7+�Zz.c��wc^��*9v�M�Ea�d�(��1�����)��R�<C '+E�OJ���AD���A��C��$~��?����+���E:|��Z�}������n���'Z��4��V�������z���
y~2�6�&@���J�4sM���0Q��w�N�V����r���'�s�.��9����-�a��v�B������n��T�=�<��� i���98G^�X�#��6�}<��F�0����
k�g��
�1���;��4�������}��G����%z[j�,�\!�8~?���2������,�_��6�>@!�U������)%�+:^��*pz�-���b�����jr�g@�x��fYx6}����QDC�<�|�]�������C��Bv5�\F����R�����-���`��x2�@cQ<eOg�M����{kl�q�w����I �J)��N���	��#��=������,��q��>���),����,�g��A�:
����Ie&��|0�{H]_�[Hc���D!���7�n�/�]_����������u�����b�	�	���9H�SsnVS��h�k��#�e���r�w����]d��r���z3�]`� U�5��(1-����h�p�|�@[��s�����!;0^_*�KO-b��2���)!@K7��~�w���A��k�5���p������t���[�^�oR`Q�,�<84�
���%���Z|��E����F���D<2mC&e`yP\J��Gkg�<m�F�OF�w��-�=�g F��R�>'Zy�����k{�I)*f34����2c�����������c�$6Fb��O���
�&��#yV;��y�K����np��@K
���\��������(Le�y�r��B|1,�*#�W�Z�LH\�@D�8�*CT�=�����{�	�<.���~n���Z9
���p����Y�^��n�$6��*�t���&�����e��$�*o.�:W�������j��x�|9g�����(���7N��o��Y"/>����z���S6�+��D�w/�v,o�]%��/0 ���L��9���*���\\cfH��GC��g)�Ry�
G!�Xu���.��q4�j
{2��C�}�i���/k��N���ga�=���%x'�����yI��f�9����'W�m�
xx���H���a�/Q�*e������)R�@��������bR)�����i�0f5����A�3�^�X�{.�~�A��A����y�&�
�,R��Z��J�M�}�������,d�@��^�F���87��I�p���g�`��$��+�?���y��K��V�!A����%f�N#������9��?E���y7-�F�d�W�z
;-��q�����*�gy��+���8�t}���5j;�Mp?�
�S�Gq�=�Z0����J=�_*�mp��a�<.��.6��������q�=��J�V�dF����7�%s��U�n+��
?8�),Z/���)�,y4r<��y�����D�9�{���IU���w�R8}�:%UX�N���n|�nC��[;�������+���2���	�1�K������q��b5�S���>GS�+A�Um�h���5��s}������<������b���.�5�.����%�����u�_�tgr��:A=F
����M��<�!�N�f;l�����r5j��t4w�H"��Om*K?Nlo|jw�l_��0e8I7�)�1)6����q.������^���8��|HQ%��V��@�.�O�C��Md.|�(�>m��|��9�������nEEk����p�����3'�jx�o~w��b��R���e�<"��Lv����G���g��,OZQ5���(��4�r
���:����JrEp��A���{
7���Bc�m�g���u�[R���&�����n5K^��� � ���-U"�hQR%��������a�T_c��`O���U/��C�h.Z�����<�-!�Z�r+Am���	��^I���P_;V��O9���}�TZ1X��ad1$�������Pq����$�;#gebk�tX��p�do�r1r$|!�N�Z{��St?$��Lz��J]�(u��@��:e�ES�YLp�k��9����p���e?�����q�����9-�i�����9�]N��I�*v�V�����;BnEnGL�8�L@�xE�����u�LB�<e����p���4,����7�&K����B^9�q��!B�=�t�$�~_�O��S�����~�g��
[�Vb�#���l
���,�����������;���5�s�W���R{P�/mQ�F�E������
p����:�����K�j�r�iE��!��Z+�����1?�
���v���&���|!��v���:RP*5�i�6� �V;���*C���9;�e�1&������6��4�e{<�y���tQ~�[��[�^Y�)8&U>��q�H�w��`���,*YX$������nm`�����Yb�;�
�����	��5���;\�N��mBL����?�de��R��a������0K�x����q��T"��*����.��sti��"���S=F!��f�g�;����GQ��0Di Y_���
�g���5��D��'��Mx�����f�b�L���9]]��d�`tr��N��s
��S�^��R�P�9~��ihD8)8�6���|*[w�ZF���U{_���V��&R���V%��oy/��j���X(N�x|�}�S�R��q�������q���+�.H��W@F��������R��;�z�Q�������O���[4a{�	�8�����;� �S
?tFA���{�"*<I)��t�{�aI]v\[w��D*}3_���w����*�%W{��	��F�%�g#�����G1? ���I/�j������������LY\�bh�*�5�;��sD���]�b���-����iB�m�����H�^[�����+���b�*������Z�*����I8�M*�t^-�J�S�� e_������������o0pm�C�0w^_�K����u��:��������7K�b��3���;O�����(��jG^���
'U#��Z����T7��j�(�����/�=�����{��"7����������y�}�W�OT���z�.-F��r]����(��=���S#\Pu��|/@�����q��h��={yq�w���0v����iVe��=�}����]=S����M������V%���g��LA�����F��k(T�^����6��Z ��/������������-�����}/���������^n���}���j1�������k��nN����Q7�Q8�M����TjW+��I%��wR�X[��.V�n�*�zp�b��-�85�N�(���j�Zo1��Id�-^��v(JK�8y��&��p���*���q�:����6��F�>�'�@��V�������.N�A���ViBl�t����	^�������~%��h	#�0��������>~�~S�)�,���l�pZm6k�j��'�V�OZa:%�I"P�_a���y������77����z��N�����J�z���/���R���U��j�Tq�f��~R�'�,�O#e'������7�[��"c����'r������� a\�jP
��be-)z����J�������������/���GR�����>A�n�f�/J��d�l
��F�����t����h���3��>�L�����. ����r[�bu=���H��,"[�5[�V���K���5��N��Fr�e6e�_f1����&mB����j	�tb�L���?�I2YlV����MGl��K�����"�I�������`��Z#s��^��Y��P��S�<B����@�3y��[m!(^QENK�G�������\m{ ~Ff+�z>����)DC8I�xP-U����Ca�*
0003-JSON_TABLE-PLAN-DEFAULT-clause-v46.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v46.patch.gzDownload
0004-JSON_TABLE-PLAN-clause-v46.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v46.patch.gzDownload
0001-SQL-JSON-functions-v46.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v46.patch.gzDownload
��@^`0001-SQL-JSON-functions-v46.patch�=�s�F�?����3v���|7o$@ 4	�tJ_�,�Y2�Lp!����w�N��C���xZc�n���v��������u��;��k����v'��~�cLz;���t�����{����9_���t���u:��	��#�p�5{��=_��H���
��4��l�V�h>��l��.{�����e��aow��a������/'�������.?c���/v����/����ti����^�2�	|���l���iF�a���������niK�{�����R���<?g��p�a�@q�����+���hl��������<}��y��1�T��f��Z��b6&����������������
3�����ln����9k�o��A�n�,�B8X�=���$�\����^���tw��^��w?p���i|���f��W�6��#���c�q�q��t�@�vs
�s���B���n@y����-�����b��C�{Irm���z�B�y)b	n�������_jV,��4r�]��A��o~�+�6�Y�y#���.�t�f����t�97��n{����b���2��$@�<��o�EVF���$w��������J�O����������cY�������Q\J�\w��eqU�E�k���	$8t?%�*\z�����C�zm���`��`����u�`�o��4�;���F���^�e�Kv�-��^��$ �x�&�7XCn���v���'�E��s��i�1Z����a�,����8]���I�3A����gK=gY��������8�jy�|aq!?���uki�6�����p�f5C34?� �����q��z���[�e�A!���c):�f=	%���32�Y0!_�p��9�(n��d��<oP��HJ�sum���Ik�

�Q�F��q�����f�o7nR���^��i��%���4i}��d���6SMGB_�h�E[0�����J���=�2����
��zsC2��8��~'\�l@g��=�6�UM����y�eqk����;��h/&ej�`��������_�K���L.����iq����=�F��u6m �b���V��;]fp����V�b��)k6g��4��}���&�BTL���nO���TZ�]������0D���#��i��nrz~��5����p����a���r>�8Z��b�y����w���^��b�^mU��Q��>u�ic�i����3n]���zHP7�=w��ae��t���b���	Y�!��������a��O���n1�P	�������y��.z7���z�s���c�5�n�;��3�/]�����n�S��K�Y��M�P��_��3�5���~��i��J�0���{LNi�`r��y�j�������[7n�~����D&����"us� �	�]�I����]LZy�P R�"�g�����������\��c{iY����{$|R,V���
���k�r�"z�h��)X1��+/��T����^d��|�Su-S����	Qw�|����y�t]���:l)����l�mm��-�Q�)�r|~q����:0�G���~4"�"��@��an��Wbl�|�,���l��0����+��y8Q���7������c<��Y$r]T��0����Qb��B�z���6��r��F Gb���r���[��1}���?0�[����d�3��M�8�(�3�{����~���G^���3��eN\�]�QXAcj��o}����Qp�����|��+&������0�ZE:��6�)&p���|�\l�����-��ff?U!zo�(M�x������6��O� -]=��l���Q��h,ja�J8'���M?�B`�����#��P@W�v�e��4X��B��	��[���C�94�h�Y������D4���1�$���`���h��Mp�4����D7[
�s0x��l���d��vw��k!S�����D�T�`���7\�d3�2���������*%�_r�����|'wb
�3d���'�a�NM�0fSF��e�`F0!���\"�Fd�����:j�VUU��le�ZM
l'���#�Zu�'��E����E�I�
i�����w���
4�`o_���A���n�}��u��0�m����X�gf�W|12Q���o���[������"dxlD��T�E44X�i�-~��N�Z*
nL��x
+G=	(T_��cs�j�B�`OZ$��
l������Q';f;p��]8��9L�l���y���q}����E�sPq��4m�_r�In0]�F]%�)�2�~{�������D^�T�1n���mR��K�d��s��8j6��6(T���a;������e���Y�+� ��B�������6����� >���X�"�Y�a6`�������J��Cd��7��x�F���Y���h�++v��y�` �K��	oES�]��4�`=����/����`;�}���7�����4 ��$��y�^N���l��*��c-�(���r�V�2���i��"W�Lz��)/a��i~�m0����\�N���3��1��|�&a��
�DLx�������6��^�#
�<��1	cG��q�M5h������_;l�:��&l_1��v�Ul
��yV��>���������	��(�}����4��q���r�������e��4f!(t\+1U'W $���`u�����@��f�*��p����Z�
������u����FX�H.�Yf��1����r�����K/`�]hWHK�����b�7��{�%��/<������ZlD�n{�s)��c�]0��'A�\$2Ak�N|�R�2��N����+j/�����+*6��J�����r�����%���G/���AB��>�����w$H���i:z����E��$�������GN�����(kKs����N��2W�"�|�T��[���3=�P /Y=4��F[���he#<B���!;9={yt!���|���������7'���������|b�?�x�>�?�o.�
{����o��N�9���$����7g����_K�9z�xp��~�������+Pfw�Vz'�o��
'����	#Y�JO���&�������/G�+��`ob#M�f5����y&�����aRb�f�:�P,(���<T�xfF�$�r�L�"-R�j'��HFe���9m���%����P3g���B�#]�t�4{���rg2�+}����o��}����M�����Z�|_G�.(��H;$NJ�(��b����SV��
S"��Y����kI�Xx%�'�,�H����b^�q�1��,#����jCs�)Kg������������7��'|j������KL��s�u/
 �r��1T�J�(���#������mo	�e+d�����z�"
=�X�!s�RxK�r�#K%������L����
�T��<.e��=I/��������OI}H�E�+��%��y&F��<��f��|K&����T���jP^J�2a�v��)vE��<����s��M�����������;�h�����^�(�"�F����5U�Y��:�T��EY�\#Oy�Ly�rd�F�\���^9��%�8��,`��T�������Mx�}^�Dr�Tr�)W$W�0u�������YN�a������t\��=a�
�V���U�u���������_��/ �%�z��jU6d�^��������9����T�_
��:��*��a��e�	��Oe��������v��\�z%09S��� x$���	��f�9c�e��s�F��$>�[��\&�&���)����
��)�8��B�(d�%%��b�.JN�azF��D�>x�����=p���"J��}f�,���1�2f��m��Q�]F��Ea����nn�Yi1�v�.^6��>*\�\��e�3��Q*
�Q�,�:#�D�y�������G�cq�nc�0�Ou9��	�p:8��NzmA��������=��-X���J�(�7�A�Y�fbpp�-��=�c�B��:rR�RT���=��W1A�4�Qy�&X^bI�GQ����{�����R��w����>�":��Fu�2b��s�7U!2�R���oN;e�A�A
����D�P�[�{x<��`��R�'J��pS���'l5�V[��
���p�C��R0��6�����(Qd����������|+�31�p��|�����~;z��gV�0�Q��"����� �N��e�Wo^�������-�MM���V��~G,��~?n�k�6�2'�E�q0�<F���5��d@ lD�>�pF)����[�a�Q������]�9j��*��q�)I75�hM����%��"Y����e`a'UT�Q��^��x�;�.��90B�,A�N���J���R!O
c���{G����c�,}&��2:�I^0��%����&��O���K���/\����x@���U�1Jj�:����7�/)�f��hK�es��7�����I���|��c�X����
7^"��QB��P`���d�����`����[�{��|_���"��L��o:�#��t����kQ�Px
*���9��t�K��MN�:Yk��}��Y�d��~f%������[�����8���cs�+�\��N-������LrR��M� k�az.��$������JB��Z�z��aV$e�e��0>���>�������<)6bi7?c��8}���9`rk]-<e�N�J�3�������<����9�O^��\�"��������i����<�@a�=����~S�����S,�gW�0g��f�������
_>7_:���B��d8x�F��d(����k��J�"/3/8u�x��(7:���(�9Y��!3��l<��u���N���"/-Q��PVN^��T6^Ma����0d4��_��Y�:����C����`�nm�j�Yk�����m��_a[�&sMt�����y+���w��)�C+�aX�$7�Y�U(�������`��h����,�w��,0y�����`��nj=.���{�$����z��^�s��w���\�{z��uH�i�-��j��[������t�5/`LnV�6)@,��S<���8�@5��3��
�kl�.��W�e�'��-vtN3.>u��OX'�TE���MBb�����dS?8$���^C�^�[v�%�xA�=B��D�/@������N{�!��@r BtGNaVwn��;	�<	�p$��������p{���Z���Py=g.���C����	2�D^�z����������x������k���	��/9��d���bO,��v�
���<��i�H��TE�tI7������$a�`������r�pcZ�������-��E�m��'Ay=�w�(#D95��/�9���0v�7)�^����_��
��3�K��(n����97�1���x����{��fJi�;�-�������nW���E����u��}�^�

+c��������T��3���3F��is�{���#(g�o��.����������ka�����fWH�zm����������v��@�����gO��be��H�,�>��drY���Y�{�$�`y��m���f>&���W���a�l�U�V�@JE!���x_|������HsH"�m�_��s#��7����:)8Q!eL��"�'`�>���x���`�y6�R����I�dN('�I�PPH�z����?��YD��x����C�y��do��b�{mz\�x:��tS�IV2��7)k�j�c�
W9�������Y��k��m�\����cq���8����������}i�_P���������f�������}q6�8��RN�7��b�2?��������l}a6�o�5��@}��l�h��E�1�>�c�|q��"��Pf]��v��+�V���Q�E-J7�U&?qU�����+=}�	yAC���`��?F������sYS�Q1�����G���*�0kZ�H���E|"������!{B�Y�0���<~�b���,Qd�����
��K�\q�������(��z)30t�n���l���k����GT��)�-�5kU�E-����t�&/��g�eC�]XD�AyV��:-
8K�Q�Y����f)��*UP-����ZG&��Z!�K���%��&�P�g|������9����w��P�7��������z�����{_G�0�7�c��-�������A�u��DoN^�t@���F�f����/�=�3#�I�<�� i��/���U�ui����,~%���d�'��M���l|L�f������x2�,������Fp���Z�Z����?�����R�P�������d=��
G����N&=Ugc]
`*R����7��c��I����sz3�A����&j���n�Fo#�(�Jp��1|�33��C��p����?�f��XpgT�%a'J�O?�.�S
�u��@��W��inO
���"�����YL91�e��e��1���9�!��9�w=A��zlm��K[�y�-C�*f�s���;[�����������|��wk�����Y��lwT�2f5RK�3�n-J8��!�2��;]��0__PkEM�}(n9��>�K�?�����S��W���(��t/rg����{��:������	w��������Y���3y'I}e��������4u9�S�������.���CzbI{�f����6�]����mM�LAyY�e�RS�G�PT��d�$���ab��2k��A�+u=�vu�[������G��3���w�7���_��������b��<::xI�c��Is�3Gz�@���`I]�HSJ@7����H��d������/�$�~��V%���y�������oe���/g�]m6��#og����G��k�-�4�������w��7�[��,��CkZ�%h��W�7���r��1���&�T������w����
x��_*�]�s���cQ���� -����������8��}���kA��7
��&�N���ti�\`5n�l��:�����c'��^y����S��7��)_���TXT5*��<^"�mT���4���tQ�%�^S�����sw�8���@�u�������+p�'��r�VzA!4����H��p
)fTbS�L�yfTD��56��2m_*�x��L2��W�,�'�	�^�jmT?���BK��hJ���K�M
z��w�s��}~1gu:����X��UU%m��t��P]�B�{t9�%���"[HCs������4$�V9o�F����+�Yt����(i��)i�_G����)d6�����X�������q���������.z�x��gx��&���1l�B����]����%Z�uD�o)�D�:�b,�,�9l<�m��m��V�gN����4n���kxK�c��U�f���mq%�������	BNB�V��!�F��-�����bL���(�3(��q��_D�����w3)C����fN����H�N��V��Ai�@^�:���A"��/������0�����pQ
]^����D�������O��I�C�=��,���sb�^�]h�����n�,~�Pw�x�F�,a|��y������v�f�o��lw���C��8���p������q��V�I���c��7't�p����#Q�'%��E]	�������	�J�y�4��ER�OL���a��:9�?i�;��Su�d�Kg�	5�YVF���Q�q���G����K��� ��Y�����0H\<3s���F�5�l*a5��W��^���h&������N�7@��)���kN���D��(��^�z��HL#��)����H6��}1���q'7��i������������t�1���b&�..��>%���=$r�S�l����Y/��z6Mz�{�7���L������n"��+:��/��>M�
����[i�U�����t`?'Z�]����]�e�����6H����#au���Sg��S+��[*�3� �d�[��~�������Z?�o����I��w�+�^tc���F;�U����d����H�Mn,E�S�Ut{�����E� �G7�]��uRZc�<(?��pX�de���8�kE�$�Vh������2�O��o���d����h���K��;9v�5�����\L������)V��T>am�M�b=�Sh��D�}�o"����6l1�~a�|�Q~�d���g){r����G�6
��
����k�g�>F���>�^;���Er,C����4���v�	�%�� S�C;�]�y������q#��4I�������"����,����Ym���'|0���e?=�9�[T�{�2��Y�N��<I6�`�N����9�uj&�=���������H��_�G�?!��xW��BX]���,4G��
#H<}!��
�^R���~~,R`�_�	i��6L��>�=!hYC?�`Xlp����W����8H��w�"��Gs�w���o�#�XI�K2�������#��[H=���=�-������������������q�����W4C���p�(yVj�L ��G���2��0��,S)�	*�$alW���w+������a���
��G,����G��^vQg���-8�t�7l3�
R�@����2�*�og����\������������������*���J1������o(������jvA���rH&�\��@	����C�A��=����	p�`��|b��m�]RNf�9��]�h�t����B�\������n����_i���{����`��kOh�rR��
�o��|3�d���A�p6��m=�(I��m��;�4���#|[��)��l^�haH[�a5��4jK�K��BS�TV��(g�X���^����� ������w�Z�Z4�0�>�O�a~�#0HU��� ����5:�������(G�7�>J�B'"uV��mF�NP:����������BJEk��r������*��<fR��x�����u:J�G
0������e4�]�.���.��7��oF�����zmu�J�\S�K�o��6��kF����w�V��|tP�O��i?w@!X�� ���4�$�������<�=�T��~������\/���4*O�J{��|�fu���,��%���L��\�/u!e�	H��h�����7V���� z��6\Bi3�N�����kE����|X�u"W�����Y��o���\!�2�{+����?��?����+V�'(�x��::hv���:0����+�cNr�PB^��N������a|�h��Z���Z���V��������~��~�;'���s�R���=`1��+F�G����q��Z���h�3����u�t!�	�B��X4j���Z*Q2UW���]����9Nw�t����V�g�+�^' ��kO+���?���(��B*h��r�������s9�������7�������B���dL�E�����D�{��K��_�9�s"�#t��_�4}��sop��/[WF�P�~Wt������s�q�cy�X�?����i��s�XA�� L��KC��|��X�E��>]������'�7�}���b�]�����_��7�6�=��~yK�{�?���B�������9�}t	�����"���������4='z��\M��9�D�hI����]���>?>��"�������0���7��P��S�}&��P�k��<��Lx��M�"��T�Y�[`��i�N��o|�Gj��+���%����KSW�I4p$��l5�f�F`��Z����j~��:��3S�����C�f�C�d���{���[5]|�;V�nw<dk;�{�?R��[ ����~����V��6������?����I�x�2�%������U<1y�	�}	�d^?T_�>$x��c&���g���8�l�{�(����}�������\0Qx|r������$����!N(�j���iO�8�c/����hnl�������`����
\��O/�z3�E�����L��W�<��[h�T4�����jN���|9�����H�+���t2,��G�7���!?�VR1G���u%*��}��[�~+]�M��c���e��,���h�lBx��'�E���.'G��c:��J������#�����,���Bx����Z�}O���V���c���M
M����C�8Lvgv�B�A �#D��W���Y�NQ�c��h���Skj[�� Ob���%{��H��������Qp�T�!��f��`'�O^���{������g���+��d�t�	��]��#��iir�Z�sG�r>������)e�o��gl~�Q��������)V�W����6b�����z����++-��C�Y-�[2/�%��"I�"���Bvc+���CF��L���8��x
-dkG<���`�'S#t�)�,���Ak.�4����Z4:�ok�9i���J%��(��y�[�si�W�.D���,4�O�����<A|�����	n%��H����Tz�2��.6�Z*2�	������[�v�=� ����+}i�+�g�K�����y��0*�@L�>
��=��KO53(�4�f*�i�����IK�}����/���%C��>v�����V����bq��ny��������������?^CA8�?�7V��o�k��2�-S���3W�8��������0'Nz�������F����v*��{!k��mF����v.���a�\��<s/����Nt��V�+����[���T���f��A��.K�����"�-��F�b�1M�]��r,L�:��%o�H?��#�6�C��S�X��'�TSE��
��H������+)F���_�R�&�S�������J��"9y���I����K��������W<���V���*1/��~��������]��H�wi�@1����i��7���w�,3H�~�8���4�u!Q8d}�1�+��m
��mi`�74:�F
&���8i����e�oo�����bH<~O4��3�B�O��b�*��I��,i���}�[�g1{Ny�|���=�%�Yo����O��jO������D���d�;</V���f[2��(4~/��Y�3�L��Y���q���z���1?�2I����~*����BE�R�it4N��7����u�+(���`%���_+��(Z
�F�|�&��PK�#�1��@I��J<L��X��u��t�b4�i�AO���� �B�����P�*��b'	������J0^�s��,{d>)'hD������[o���r��f��<���Q��sr��X"|(m����{{��T��B��t"��R92GBF�i:��o��``��W
>b�(�����)�B�R����"I�
��'u�~�8Wz,$&!8��N��E��y>D��%��B�jP�����{����t'��_�"�������3����%�L����k�������Zm�W[�j�����7��zT������
,����-8�6rJ�*�,P�����>e���J�S������m_��D=5���i��u2�7�2������}���]��j1Us�
���%�T~W����������&�:7W��[�b�����3z��@��p�=�G�A�ryre{y��N\���Q��'m��������n�1��ARs�/���b|<@�T��k�e�A�J�-Om.B�c�``�@�#�|�#_;��(�����s�Z��]l/#�������l@36�{	�t������V��w����,���}}�m���\j�����	!3�l��i]��e�S��=�Qc�vH��R�M�C������m.S���N�,{%��]��������=���>��|=F�$�?%{[�%���H����i���Y���^�j�G������{UW7/�����������F������{��^$�Ja<h��K2���d:������=�"���TN@?��GS�DP��g
s�.��|Y������Eg�.>^&m!/MF�B���iJ��p�w��Z����y��e9�}M��_�&X�0�-z���Fm�2k�6�Wn �����}����+�����i_��c/AjR����������e�-�%>i��[S�|�
'��TY�Ad
�Si�����U���g5�����bo��4�
�]E?�a�H���NDas�Z��-Jr6���������i�����2>�7��n�e�Q�=Jx��J����������M��A}o�����X�K1��w�� X����4F4,�
���\�oV�B�c��Q�\t�/u�G������Y��c!���;a\��P��������F��'F�?���
���������)�����H2R�����X�6!�q�	�LTG��_�1�?H����q���?Y�O�����!R����K/�}�����qv��z�C�����L�w~9~�"c=M~�����b'��S<\��Y���5����z���������m��w7�v�����������E��`eee���|��]�������y�i�|_?|�Z�o�A�?���g> �4����o�<�Yd�2�~������>�x���;�W�����I�]���^=E#s{������_���|:�/�/W����VN
�V�xs{�lksoom�Z����Uw���Z��D��W�cs��/h?D�5����8Z�����S�],�K����|4I��C���P������%pu��i��$���"��
*m
q��[0�����: _2������h5d^�Y
���0;���j���<��q%���8����hI���ei�D�����������`:lNFsx����=�L����qo"k���d.�yt8J������	F��}�H� ����+~5�0�����
�N{_E�`��.����_�b������� ?��[�~������L/WSH4#��T�3:�J0����W����2��{�Hk����R	�	�]���e�c|$�7K�AT��F���=%�������@,J�Vc4��>M�]	tQQ~�BCO�_����G�F���������n�k�TP�N�.~p����<)I-���'e�eY7�F���zc-��Z��I<(�f�����=A��]�I���8�!Lyt�:�i��"�Z�^
h�P����ur�X�#��dG0���7���TG�HtR�����O�i�$�S|^S�|a��5�,&7*"���JX�V��l��s�$��k��4�� ����oK�fn�UQ~?[z���W�--{[hK�fo�U��^
n�U��v�Wx���~�����z��'���~���o���[��Mo?(q����=�h��|������
G�S�������S���_h����lM�6��6]����=E����m��f���ho��j��+���sp�v�����N������0��Xb�>�������_Z��������N��{hC���Mw�����<rxo�a���(����v�'��]�������K�o�RlI)�Y����C�bR�^�t�G�Y��p���������O��%�iY����;2���/��h)��l)���G�H��M=H����T�j	�A,G���������mX4��Q"�� ��G������gU���i�6�0�A���qA�5H:����!�i��8��o���(����e�R���u8�q�z�s8R���K��*��b��x 
"�N�;p�u���|~Q�Ge��x2��Z�RR?��sp�]:S1�b��8�`�%�"��s�����IuN���v#z�(zHuH^�~�MS���Z���[�Y�	�R��M�F3�(1�~��)P~��y<"F��Yx����$�a�u�������;��kxC�,���"!H�����RG
��x<��8M�JHm����pd�k��Rm�Y�)��u�j�����"7�|CP��7�(��bS��ZdM���=�6�1E��hP����;�g��f����7Q�����L��W�h+���*L'��:�6�����S�z����`����s/����F1�1���/��</������=�w���=z�Pu���E����|&����`eE|��K�XJ$f����6����������YIC��5�)�F6`I8�G/���%��F�su�Oj�KV�����6@�&e:�����MX�_��*AR��a������F++��C�\��Og7W}��s8�FC�@c4������w,����} �rT��� oc�.�������J�MX_|������la����u�K�Z;��=��7�����,JT��eX����=k�P[l�)�����ET��fW�E��"�_����$���Gh&�*(Y��geB��hr���
r�J��@������l���?���$}Z��6�b��)#y#��@�R�P�
+�f^����������e ����$
�.����S������O�����b���8���lh����V��g�wFDc��-68	.��@dx���U�fmj���|�.�z�����D�	Q��]�-��LA�iA����N�`jBi���!A,_y�n��`���]qd�f�E�PNM?��)<��5)x��V_���D42���
��^�^x�A�m\��]��Q�JJ�%�J>�z����p�
���\�O������8=N����q���x�$���'3H-�(�Qu��)�a�Z��ST�k1���|�A/���P���f��R�p�4�*%�����T1�*�x;R��S��T�"<NR�7����UN����q�/�C����k4�����~/�T����h��O�YJ;)[?W_���O=��R� �X�toXY	X^%	RJ�����?r���}��e�Jz�7e }���t���YOHOV)���Rm�*����9��6�7c�t+*V >D���MnAQ$��DR[KB����fxl���k�����(�F�	�*1�3��}8��9�9�G'���?go�5-�����P�1Ph��@���j��&��5w��>��4S�������i22�d�XY�D4<�Y�:���@l()����^�U��i�����ke/�"�'�}��K������:���BP��$�gx���%��V���'3AZ�'r<7�E��fx�)�!P����u* jq{\������U��m����nmw{�;X[[�Z��7���lsu{,tu]������j�����:��W�,qyAo0����E���O��X��b������'���y�j68����c8��'y��-8�iC�@9,j��5�M�*����F���Q2�
/G�y1��<cx��W�R���S*�I���X38M�b�]��h���L��a���Y[\�J���z�C�S��}ekx����e|�_��
,�~��.��������U�)�[��r�� �b�ln��I���`'"_�2�@3�*�H��(	NP�G����F5,oNZ����7���G������A�Y����a�)7�^��*H
��EP��z��y�������AC_{����f�G��������w����vEZ���Bu��W���+����bz�R-^��<�����#��ob������e�0�Bj�54��^8E��hb
I�Jq�X�}�4�S��������FD3�]�G�.������c<��Y�S�\
����#P��=�OAN
W��Q�����/{}��.��4h�0��#i1�K��L�[u�}m���z����>��G.�o��4�)�r���W#�����!Q��+��2/<��H�����%���X���/�k�us��Zr.�i��8�q�.�	V��T������S����%dN#����[�������QT1|�a`Co�yG<=&��-���B��F�[ -)����Ld
3J���o:��~,%�W���5�C�>u6+�Q�R(3�+[7{KO��P�.w�[�R��qp6eEK�O�S�^D.�Q�\�z��h[�,}r�29~n��_�
���[��<+��
�y11��B��/u�&��D�.xVZ=6Ty�v�~~��a�1���\��J�0��D�o�pz�>�{���W�[�8 ����x�E���.y8c@���� ����fe���Z��r����E�9,�W2]_�-M��Qim�CD��%=�W�?$a�~�B:�@X��O�������S�f���p��+�� ��[	�oZ]���+����+���B��j*��:biZ�����"�0D<�cb�U�6���M��y�G�5�u;�������i�NE@	!��#�e�$���x��{��|�1���
I!e� Dk��o}�PL��F���bg����[Zn����Q�Y�y|�H�@D��<���{�8	
��(z]?l��@�Z|���&����)�j���j2�?���Zq����]Qn���d|���8�I,�Q6p�=t�]�=�<�)7�=U
Cz�H!�����>�] 7G����62�R�)7�a��=��o���<h�H{��v*>�[U�2�K���{�^��y�=i�:p�Pq�C����l�Rh�X�LR��Z���=��1rN
w1���z2�M0�4q���
q�������CB<'';��7��5�i-��5�\���lD+�������������7� 3���$>+y<����q<�����U�x_
�G�omD���4�5�!�����Eq7�a�S�*���O#'2tP~w�7go������DOT�:���a����>��O���Jm4������g��%~�x[��)d�����{�K���b����]�c���A1V�7��f�6.�n�>�
�3G6h���/�S���&������);=�����5�V����G.��:h����pS��,��!����-2����5��L��Qp@AK_�N��6�����Uf�RQ����,j��2�!�M����u!���:�������z�T V�����b�-y*#���d2��J�`�$�����u<2�h+^������U��E$%-9Jow�|���s���6PU��w�����%� �&z.� ������Z�LM�������V�=z���gm��FAq�F0�����c)�6H��������:�`{�d�[��^�61��#��4
��,k���U�kfw9ji���@��^]���$�-U%���{J1��8�
T��k��B��]E��������)���������g�1�\���U����+j��D �&�zY�!<?��3�KE��x0��JP�Ni@�@?s=��CbF�.�&sA�%)�6�%��l�<�]��?�?��=ni��V9�A_���0%I�q�������1�O�����4]�v�j��C9R��{SC�r7s�R|��������^�.�J�Z�i@ I�������&�������W�Y1�E>R���1�I�1��D��)#���]�bv���;����r�>�?)�59�u�j���z6�$�]�O�3SQ��NN�S������ok��8���BNE�G����2��D'2-e�y�cs��L������B��n�a'���a������D4�7��8(9Q$5z�������L����Y[V~r��`�3Coa�"��,������
���W���yy�1�c<k&mq~�D���1e�]��[e��Z?����`�������N��::|oQdY���Beu ��9m
��������������}���1�cU�(�����l�O�4���~�{��r�m�1EVf��E��{L��/�U�����!�`m���v�/E�c���Q]_��� X��[���m���3�I3�?���7��Y�)�9����x#��g�1��P����F}�ZHb����z�!�=��
�j���S*�N�]�&`�Mt�Y����2�iw������Vy��6���tdx�	��M?��SK&s�	.-��\[��O�z�
4C=�3���Z���L�wL��u4Ex>t��Q�������	2���xf*;���b�a����������&�`yq5�l�z����zM�)[��������������5D]�7T�#������������
��$N���A�Z(CcZ���P�?�b�=`�0}�,��<���P������7���`�~
_L���N�J���8��������A�+i���q�q�iB\h�~2�='�`M���N���'��������FX`|N�Z��M���[�,_����
�&0�cXRQ��?�M�|��a4a�/������<N"��#5l�FP��lD5��uN��%���m[t�d`���\&��0����S�D!���F,R��I,�@�hJ�Y--��To��.����;�o��0�H-���fz���X%����	�Or���
�L�nt�r�����>D����[�Og�*N�cp �O��#,HA]m���toZ�p����e, Q��Cr>�o`��N��p@0P
>���� �4�m��@���`1G�\��������v���#�9Q������p�&i�����S�{�J)��KM��QlU^X�m����R�X�����5����LvS��+[tS�}L��Yz5����D �	i7��3� �#�$xLvr��b���b��G�FP�d�pfq�����"@J�Z0���j�����,V3|�P��D0�p�m�T��R^��?�#*#kw[1G��sxh=�C�d:g���&��T�����i�t�+�U�3s-v ��2;1��4���������?g
��t`��V|e����#�u�s�`��>���p����o)
�|!u���������)�]yI�in��p3k���!g��VH������XZZ2���^k	���}�@�|��#�@ld
���r/��7��\��Mo��T�$i��������PM4
�����a���
����Q[�&���M��W��P��x��b��kv��qt��t_5����H�~���Ac#�:����������~<[cUM`��daJ�����{���i��qP6���_&��eG-����V��.�������7�!������L�������h���E��dvz����e^^}s�g���[�XY���u�I�0���
|��*{��N'��%�X��sr��<���q���a��������B�B����Q�n���l�J.j]��6�"������MHT��W�����F��Y!���204��������\�Yr�����C�7�!�A^�����)�t�����K�*	:a&Mz�.>WixE3�T^�4�C�u�0��N�0�����N�)���dB�A�+�a�����p�c�l�|������L���H�lX��Fo�������S������J��	�������<���e�QL����u(�-���0q4Zr|B�����cMg���'���0�VCW��}���T��+���v� �
�������z�z�pn;���}4����S��'���QG05Da5�TU�� x�=i��XHB����L$���=A����8� a���G��s�7�v$~�����=fZ����d�TL{Tg)x&JR9�^�F2�O�T$�DL��4K�(�,��NT�Nt�Y���n� ��0��]������.�.����Z���&c4S	n�S�<`��9�]);*7@[���2"��8v;���� ���-�$�����u�H�Bl�h�G�������c�h�\���M���	d��ku�;��s�9O#��H���X}DV�O�&wT���t�?�o��M�b�Iz$������L����PL�8�w�,@4f����� 2��8��TG]f{������}�����.���A����c�Z2��f�����9�Z[���x��[��c�����B51���&z�g=��Vw@9��j���;K�����l��f�>l��x*���WB
Y��?���II%eD	�I[�sP��F�kwh-���/�%��U��]�Zzp�FgI�8V3��z�C���Q1|NA���c���
��r�!U.�`c���]���w��j��~\��6�0��I#@�.}mg�>7vp��P�6�g���B�R��a���������)�;��k#Rl�(�4��Z�s���T���:����S�e�Kih�%��o�WZ�����A�L{
����G�sS|����}�� 	}\��H
��VOL�����LS$�SV��+	�D��P9�B��(o���(��Uj�40t�����t�aJ���U�P����S�����U
���b�,���.��^����=���m�$�V�=}^�!`���.
���*
V@d�%'`MN��uRN�U�-Z����zA��-
]����VR�������8�����-]�E��u�.�A��^@Ub��z����s��IU�����K.�$�2�H�6U��v������O�DR53��=��������y&��r�v����t�8q�Z�.P9�8?������Oz�x
�����)����HL*�������i
�����$�E�(6�}t�~��8�pq=�"�X��CJ�q�����/&�Q���N��'I�
�[��aoB��o��{�FLUmE���C��������N���io9S���
�*��m1x��c>�����rk�`K���a�V@����{!\,*�~K4�3�)��a��|��*1���j�[����h��"��,P�seV��@}�R�,T��A�"	��4(����-�hi�O��Y��T�s�O�K�z� (�,��-pX6��*�i�p0��7?M���-�Y%t�����ZH����O������e�M�-ZK���Q�!"�`�pf������2\�	�*�5��!�1�z��Y�����(��\*z�q�eR�4��3,���y�W�Y$Y��xmw�����3u'a�L���%&a�����N����c��w����R]�~U%������'}\����;���s��#���:��g���z�.��^
R`�YV<	�����o���K�D*q�zh	�^���a �*0�`5@) ��=}=��?��I7��,pm�v$�sn��wn���p����Q���6x{������XB����}�Jm���E�����]�bt�ll�Y�i���QYC�T5�jD_��17�yM���PS�>/�)sj�]��6�/u��Y�JyM*�z�5���k��@	�����5�Rp�Nk����5��vur������	������
�C���I::��4]�]��]�Gf�)�L�.2@��by
1�)�����S<s�`)=���F
5@�zx�!����b�B�h�+��|��<���E�exbR+���\X
.�%-���d����I����v�U��uo�eG�+(C��^m8�ml����g{g�����N�!��P������n
�
�Gm9�.�)dI��D��>��"�2���cPG��O�M����d��[���'�9�S��GQ�B��t�@�40��'k6��;��r�3n��/N7�G���5�<c�AR`��.7M'����/��Qj���D���1�e�;����I-`�cM,U�������3�I����I�9wi�v��ay�h<�,K�����q�8���M��cmS`|���%uf���D�N���ha;�(\)PXd��xkp��t��oCIslU,�g�3`���������&�7��*f���(�&z���"�!u�(�����mgwX�f����l7�`�|)�r���}���,���P�����V�Ex��K� ]��@��������/�\e��X��eh���Y,c��'s*��\w^�k��]}3{Ka�oSd_dX�x*x�d����LAN;|��-g��AV?	o���*�����!~�����a1��V���IF�.&PK��x��1�����IQ�b�0l��������Mn��*��^�������[��W���&\!�F��-��0��_��Q�>vi	EO)�omks�n��W6�@9��j�N�u��}~S�?���wGI�!K��������R�����G{��V������k+|C������uEPq���s��1���q-�e���]������2�Yf�+��9���;��M��s���}w}v����Nec}��~���G���r����B�����Ujy���������}�R�����Z�m�{���,r��s��/j9�";G�-�G8� �st�B@�p�B�Z����������IV.o&���ju}0����
z;��A���w3��	]L�:@
�{@��AD�5���bv����^����v��K��|����*]1����8y*��R�8�I0]!����juR!�V�+��-�[��������IL�m��79�f��U�� aSHz!� ^���	��O�		4����+�ON�c����R��(�|���t��k�a���V�FX��N(�_C��F�*�Rj�&���Yf��g�/I��XK�������D���H���W���p��jv���%S�����j�D%n��]����O>|�
� ���T���/Q��r>�\�J!�~����������]�@�[��MY���`�,I�����zWg��1�ur3T2%�/Q�������H�
���S<�'2��*m&N���u��#�����P6K��otO�;p�@JJA)����r�t��v�q��=���}��ju;�nu;���Z���� 6�y�}��y��d�]��8�,2J��k�v����,W���-y���\�5���~����	��i��
>�7
��N�� '��d��hb'�(G��s*P1� lw��T"�M�Z9���U�~H������hc��]$F�t��+������E��?!������nj`w%e1?d)�(f�dy�q��K�f?���uh�Zm{kc}�������;[�g���x;!�����\[�K|�����J1���%��{���t<�g�G"6W�Z��aT�M�/A	6����B�-����@���k�D������#s����o�����:�U�};u_�zD��eh����2��":���V���<(�����������u?Z�m����ZQI��2>���Kj�"7'�l���������*��
g�/��x������pk�Z�n�=t9�w�&#���;���.��t�<g���X���zy
���;��n�TG!]!��"��r:�T�Q��(�i&��s!Ru]|�h�1io�|�v6*;
���}��$nj��2�|C�\��EPe�:R8����@+}B'
�&Z����=U�����_g4&��HQ�tn����g��)+�R���4E�LO�����A{��U���n�-?����ec�!I14�&N�pK:�Rd?��v/�����2�#��GX��I
���NecW�q0Hr�Ta��T��EQ3��e7���Q9!
�y<�P����%W���F��N1��/Y7��!B���n�'<Q�~%5���Z,�%��EH�mzU����n���K��]-����e)"��-H�����S7�4����-�[��[��f�����1��E��c��������h�Q�T��5��,����]����Q3�G���n���,�vG'�t���_ �{�a��� #��YO�^H�=����S�Hov����dT�X%��G
�J^`-���0�E��.$=�Mn"1�xfvD4�?N��b�����������:i����2��:����NeG���;��q�so�1�I��>*���q�jd���6�X
���!Y����q��\:�I�w�=��E�4w8�C��c�.6czp�V/rF��P���������U�(���%/t��N��D+��\������ml��!H�gA���Z�-jS�N��Ao����Y�/����5ih���D}���v�4�W�����{�-���X��57���cn����K��P���g	Ui�%%Zl��������K+��7 ���70�4,�}b����_w{�q�����C��.��no��,����+K�e{��]iD��[.��=��r��;���'��3��=������W�c�
���;�v��
.T����1��kQ[G_�9p����>��k]���DH�@zs��k{��zu�Y��`��,erj�!3�N,��}����y^0����a���J��}����%%��;��;
UQ����������� 4��3��y���?�[������+��	0��xY�"MX���f���y���,��n0��#X�+�����7A�f������������R�b~�[v�e+��sv����l
5�f��^�_2h���B�!d�W�w9�;��H�r4����B���{:�"{b&^�h����FR�OH,rx��tlA( �[P�BR�G%JB�r��(�{�����qG���G,l���
��|$��[��Qv���r[$�(�G)������|��#K�>wu���o#��/����m�G	���Xl�0%&k�	�iA�XL,L����P��#){Y����X�e�R�b��\��l�3��XS���������N����B+���F�R�BYR���zp%b0�&���<R���������W���8�f1�Dp�-:�Sv!�)e��sr�aj��<��a�S�C5��J	se�����?�����;�{�H�������; 2��(H��I��Ga8��dFy�[X������l�T6+�Y���'5/�0cC}���������m���#��+��]J3�:6{����@0�xq�wge�M������Mf��w����i�e>S'�pnY���<%mTQ�n�6E�����>��v1N��a���>��'= �z�,=<s�a��&f��}�����7�������i����9�#�}��b�t����r{��:l����?�<������W�Ec���(���a��I����A}@j9����U�\�m���&�O�C_A�<���C_{��@������������L��������M����p���0c]�H��,���+��t#���v�S0��]�
�9.ps ���V�b���w��W���{kk�f�����W��Y3!�GV�Gwj���������:N0�6*����i$v(�>�B@���f���6����x���"�CX�+���|��o��/��e�u�7J��G_�N��;����4�N�Y1��_G�UL�5Q#�r�������x�L{�&vVx���9g�'����Q���=eXD*k5R1���y�I��������_����?�gb��i9Qe�"<-GY�1���l��;�������������������5-��b��M�O�y��aCp��0����87��'���L#jI��gn����L��;�B�!	��p,y@P�J���y�?��f����4�vJz���O��}q�����W6�|c�z�Se�uL<�B;5K�[�#�iG��	2�,A�P6�	�`�w�:�_����y��8�#(J��R!c�5d�X�d�\�2h��0��97�y���x�f�N�!��p���L0�T!�&!6 }a`�%2������
������h����XB�K��5���Y�X�[�����7�f.�Nr��@��y]K�j��6	��%�@Ce�f���n���[J����q.���\h�v�YK!��X�)%����)����XJ��Z�Lm!q���e.��q������P�Fh���[�,i���hC;;�����6��.�������<q����y�7vwP����6�B%G���
;��Q?�F��gZ�2����]Jt��������|>l��ba1����!4�.����Y���T4�HO���l���dL�2�V�~.�|24�D�b��,=1+�c�����a��Y2��L�Y:��]����]��1o���g�Z�NMK��n�%,�W<��ds�X���"��}?��`6{�z��(�.a��6]xy�����RH��9.�d���2>�3����tiJ�U1"g|
	��B-o�6������
W���-��Zb��-��P&2K���!Y�����<���MQR`�J<�'���e�!e���M���h�#��e\M��>A�W �H_�C�����$E������zR�VL	�R*�h6�V��<�1�����Y��5��]�����������r��%l�$l�s���
W��������d�t9r{�]�����|\?�4a'��7��z���r%����[fR9��m��k��yc�E��2F������l����7g�`s��D�V�n�e�m����Vv��F	5�u�����S�19���vr����E�&�0�,��hq'd�9�w���p��h�����HsIt�N$>�����m���]^[[���B�.g\�O�u�+�=���t0M����������W��o�l��{kk{[��a?����������p]��mloVv����5P��6�����R��!� �=��!(qM3���~����^�@�����:?^������������7��W�G�W#f�1F��w*h���0��������x�/bp/H"�GK`�QU��I���O���������q���W���x�r]x�*A�������#��ID:����k���������P��.�HNsYx�T�3n��,��$��p��/�r=��Cb5K�4���F���Q2�
/G���(�G�(�pe��%:�_������e������|&�}f�#��`	���X�����x������>����-"����=�?��z�|��.,J���%U��QE(���]]�
lz`)��
���������w�p�KK�����^���v�P.& >��u�c��qML$��O1���R����;0?FB����6c��1X4j��r8���h����GC�{|6�%s����@�lz*#U����tE��R���*F��J�:����}���X�5�����Q����Tzsk�o+�C��F;�'�'�I"s�P�H�&�����,�I�#h�����.�
�2H#�%
����q��VH�4Ni��@�0�z���
�G��f�N�9�71�g����(�����8x��%����C�Y��I�LX�O���7�'��,U��
}���6����Ju��A}�
�H4����fC�U��!�O�iV��2��"��qk�D����I�;C�T��|�?��	$�|7�8��k���y-��,~��Z���V��O���(��I���1��q+������fE<���I2�6��G����s���*����8V��
y�J��a1�=n���S�?cY+28�������({�d-�9sM�!z��1���B|�7K�!v0��u��]V���>+���	o@_H�f��@�����f{p���q���d�x��\���sj
fDZ z��$�Oq���T|��3��R�HT}�
F�Zp��x��_
��Xs1U\fhh��:C����7�����t (
�vh��|��\�q�p�L2���Fmp�9����m�{�����0���m�9}���6&�]�>+�;���3��<'�j2��M�&���/�c�5H�u(���z��F-REIX<>������Q���!����cJ�E�Oz����D��@��"�GF������KO�1�P���q-N���(�-EI<�E�dM�0ib���/���giI�!,��l�5���y(�K<����G�ix�x��C"/<�1@�Wdl���K1��y���������`P�#��u
*w�+ ���/� 0\w���6@�W4�r	xb�=�]
�\����~�fa�M<$�[G�p�h�{6���Cn���N�}1%qt�3�K�tJ!x�a<9�_D�����������=�b"�F{�RoW�+;��5l��\�����/��K�q`�,YB��(��k%)*�bx[��v�%����v�<93���z�p����1��{e.4L��	��N?V��S%��Q�\������^(O��h_Z/I��?#w� ��4('�0_N�e�q-^
�K
Tq!���es�z��`k�7������g�90���o�B�m�8��MH���O��7�.��<U��������Jk^�&Ix�=L���")qpVHy��y�oh$f���t�l��g�������6�����O)pO,9`���:*_���F`�bM��/�E��N��.�[r���|o��7�-�c�#��P�[Ar�i�A�H��D�OH~/��Q�L����4�P=���uy�^���b��y����c|��{��8�RX�IK���!w����Y��U1����]��&kQ��+�Y�s}��y#���p�-���/��������D����G@~DuTF	�"X��hI�;����p����`��� |�ll�������>TA"1���7��L��!��z���^_�G����V��%��������u����v���������v[|�=zT?8�g�����N�p!�H���H[�R������z������#�������G����}�>�����I]����L��8�N�����w8���w����~T�:���[�8i�:�O;o['������7i���l����(�>L�4�G{�~�P��u��N���F�m�m]�M�=�C+������lw��m�����=n5�L��V�/����V��������	 �N���f��S~��fG�	��#n�;>KM���������������������~G��b��5G�0���O�������;'u���
�=����[���A_�o�@����=6?i 4NZ������+��E�������|O�8i�m����`[��jM`���}#;h �4.����k���&.���O�S�b�����O��Z��p��S��IK����V�9G����~��y����?��l`��;�����5~�o��/����_�o����������a[|���!�@6�w����]��
�����m`���@5�d�v�+���DG����� _��5��nt�<^7���n��MA�^7O���[u�����u�DO��V�mB�?�z�>i4�������� .�O�h[�/m1����e\�	����QClD�7��Wb�oN����j������~���K[���M^����T���Fh
���<j�v�����j�"u`Q��		�X?��GT��x��|;i���N��_Z�������5���p	!>Z��$Y]�AyA}$>(�<�.�C�|���(��[���c�E5h���q"[�{X?���'���h�����^�*�F�����8�%<��jF���7��7
���
��8):�!�Z?D*p(�k'>�;>i�^�7�������{h���h�)���+�x	�=�����zwO���7;U�Z�H���*>������Q���|s���kxC|i��wz�.��x(��z������<hG���H,d�Hl��1l�������>D��7�*�R��:98&�"i���������� f��=T��m��=~�4q�Z?��	O�����TqM����,�q���w$(�~G��m�L������q�D�/�w���N�4����C�#�p�'l����0��\��w��8���f?����b���%Z���X���C����B���<=A��x
�5��.�Z�U�
]��l�O�G��'P��aS��
`�D��;�8�N+�zX��O1ZlPE���O�S�&|�����(:i�y+���_�a���)��������/�~�����C����
��G�m�	�D�F�DQ���m4�bRb`���H�K����k|">������6>���fi�4h�m��z�M|C3�5E�����=��Vl�vK@����m���8:|��=4��lCtadb��d����������@	�S� �[=i�3L�R�[AJ�,�%��1
��^ �r/��-�O_	�4���Y����=i!����<����.�S4B���u�}?��#j�c���8%;���$��,-�U<�vw��)��'�y#��|'����e�����vA���hw��>�����������-(�����)�
��CF�Z��h��H��KK�	*v���cv%sP����z�.��XF���A��-3����8�>�����/��-\��mX��j���P��U0	��7��qOT�<�_@�+�ZD���Sq�^@����o��ImDl�a�q�������;��1(�".*��:�R��~xR���H�#�2K�����E����+���\?�	,�x5����<��m��h�1����I�c����5��n��>�3Z!�����7��D���,(N��h<�'�*���
:��N��^�L��v@��A�c����E�	p-����_g�����?�
X��%�RFU��������T ���T������"O7�W ��� �b��I�s��Py&����E��I�)��� ��Bm4�{�1���C��������"���U`F�#3�P���@��������AN!>��1qZU�IQ*h���F���"���C�'�D�X��5�U���9B��z<��5��*�����a|6������BL��x�q�x����D�~*��+{��=`�� ��.��������	\r�J����������H����*�Q%j��5�-���f7���bp�5�O�4���.7��8n�D���h�[)�e�(i��%S�_w��G�x/�1�.����n24|%u�+\=�����bL��6YpVk;�G"��2��_����/�CH�7]C��
G^Rz�.���\���1��Y��e��}C�'�FX�i����_�"z�K�y�VY����v�����c4W����H��I:}���c���� F��
����7z�j4
KU� �������� g���lbuc}g��B�@4s�>�5��i��Xo�+�0���xf������9���nu��'H��<u&��=�:1��m��R��U���9���&1�?S(%�[���wu(0=���DdI��n�(B�x�5^�>��Z�E�ma� �7�<����	%����Q�����fR�����W��\����]Y�[�
��6�h=d3�--����|��|G��k������1K�f;*rwo�Q3�g���
D=j���0��� VL�
�k5��������&�oA����U-p���T+��j$�/������w
�{�_���g�d��
�?�%�2�A|��g��
`|�E�G��&;/����=�����a�X�o� �+�w��G�Z!�"H���i���t)�f"^T;�R$�\��$	�����7]�[!a�!2�e'p���7%A-�U�HuBol�o�����P����=��!d�%�xt��~���p�i��Xu��	T�"�����oP��
����L��f���@@q�,p�Fq8���
�8��@�E0
�_�+����`=�h��-�!����P����tx-�����y6�M*�1mI����Ky�����{R��n��W�(��E$�������*_%�Q� ���.Q~B�^���|��p��.;��1���%E��:����/��D0e�;��TJ���K�l�LQ>��2����Ude���j�DAe�"B*1� �0�
�4y������{r�7���=.����d8�<���m�ek?s�'4�T� nx[�����B����Gu��`���{0�����z��vIY�Z��@T�%7���|6<c&`�|�-�$�WW�jW�gX����6�y�"��^>���2��^>u����������!s�E�K�����6�T�I��>z\~�&,�0v\��{Y����N��/����#��HA�RR�����*�D�4����)[Se���1��S�
�� �P
���8 �EJ�R���.B@���c�7�C�H+�C�e���8�3���+J�Uq�N��hw�X!
<��jqp+�=��[k����	��r�������Q~��=�<VT:���4�.�*�|R�ER�L-��*����Y�|�
_���A"�������i�\&��h.���^��^g��P+`X���M�cY��1\���v�.U���v��^W�d����w�Y�m���[c+���o�;���.���'��cZQ
�w�d(���P�8��?��1��&�_j�"��&��/{�:j�����{�a`��"��B�5��+&��9����0�����t���R����P����f���R�P����i=5����Y�SbLq�������)M��'b����b���R�$RW�8{��t��J�����'�(��lfv����q�Uma*a�9�KU�a�� �B�3ra��]
��� ���h���1JL�}�.���F�h�P;�qP�Q�d�P�q���8����%����c����������E�d��>��\ciFB������v�`�0�NV���Z��`G�Wl��h<��t2�����EaT� 8er�������tJ/�����@��FG�K���tU�&��xS��3:�,y�7�[��t���/��xmk�]gI�E�"����)a0���x�Z�_������,
�i���go�f���Qr1Q��V���� X�����|�YY����7�q��D@�@�2����1�C�,�=���MO���a���:�S,X��l.#D(��Gg(�����G���t���zK`�w�����.�:2�~�D�g�~I�M0:�/�	�E?����'�.a���) �Fj�p�.�-����m�RN�	*��<�����(�h��A�e)-f�h����6l.����|�����0������n�4��%J�@��(��5��6!s$�3�_ZJ�����Z���w��Bl��N=���	���L���(�����KB#���t�R�T-A���_�.�N�O���c}�-�Mn�4v<��I�l���_�B��v�N.A�����	6,�n�6�����O'O+b<�t\�o��gA�l�K�H�\�m�����m�4+(�����^1����72lc���B0�R���@1�����+��e��K7�{�s
6Z����r��+������|v��;}�\'��X�+?������Q��d�2/�},v���]n�������]����&�0�����'�����K}�b��/�	��eof�����������jV�R��'���I1h�e���_�Ii���\Ph�[n_e�h��w�q����&��&����Cj����!�j��ool#e�V
�9��A
�������	20����EG��ls
��>�:��rBT�<�3b�%
��[.|�}� �����4���UP'<��9���V�UjV�9������"��:hE��Q���H��x
�)&��wO�$�>"����xJ���V����c����>��o�R�wf�4x�"q#���F-,Q$y��Y�Ji��2�����U����t��GK?ZoU��:�����'+;9)T��)z���[��w� �^v�����[�K�62i�77���.L)Lzw2��X:��}�_���Q���~�Vp�������+�2������z�-Ph�����Q`�eK�[T�~O+��?��@�@6��
�{.���
��N{�Dd��<r��^�r$��jl���������`�������� ����>�d��0����b�*~�\�����M������>\c�O�&�nn���)c�n����
����zw0�
���e������-#�s���4�(�3a�4��/z������Ht��YJy��_��!{�r���6
8.f��
�lm�(�6����+��)��g��9��kF2������S<���K�P����"��L�m�Cn�Q�okW�oSF����
��t�7��KO������5�g2j��)#7��mB(X������
O�~b�b�
�����
�,�A��O��4?)��
�UC��IQ�`��{�2~���f�<����;y�Q�/�H�>�WN�*l���{�/����V���8�b<{�'<W��x����uK#�����{���BC�6��S�Y�#���J��n�������<P=�d�-��*����@$������;�����5�~����D����1���n@�"�������ln�
\�������rtc�
)$9���� ������V�0N�m���������'.�`A	���~QDB9���
dM�nS.�1q�)�6��xV� ���RB\�e���v�?!�8��y����L�����e�g�D�Y~?�[�<��X;���Ta�0�6� �"
+��hZ
G(���,4��E,J�|"�yE��g��n�JC�i����T��3�;�������j${r��z�>�����������������2�_x��a(���r.��w=#�W�������CL�g$F��'��t�k����?�{�#i�����&~�w�#�{�o�S�IKl7�������G��|O���������!���Z����V.���-�'��W����~�M��;�(�	���X�g��^�c��|�^m;oL����(16������(�b]���N%��v����U�>[�\[��w��w����i����j����{���:z>��0��'�x�RFVq���x:0��e�x��[�M2�%T���~��B�(�V�9
A�{c��P�|��Z���G�$��[f�����X�1�?������j�O��j9kI��������Xy���������V5��*������l��(�&g�_M�����(W0�=<��{�����s��q��*W������s��N//��&O�}���q9J���h�1/:���m96>mO_��=�x�n7vf�T������tD�[ 3�8��\��C�y��*+s3���)��Vj�T����7I������8>�~>��J@�=���O��:d�����G��^�^��]V#z"�v��-����%soC�P����'�Ei���X5
5��-�%�6+�vlL�F5��{���SE�;��]����3�����S��xW��A���;gY��zn[<�`�9VGd��,O��1�����C~�)v��S����l�U���l�9<(�>T�Ax'S/��������.���Fx?s�1�BN�0T8�I����T��M�����<��</�/�Q��$��mU����p��R�s?�R�	��L ����1���O� �^g�B�i�pR-:���!��+k)
i
 M�����A�hgz$iYd8���P?�
�(�g���&���������8�z�Ho�y��M�h�+C����ioVG��[=Y���]i������VW����������:��Po��gvhv��1��6�r���ZkTQkp]�3.��:�����'����ODP_�X��E.�1�S��O;���]~.���neC��j�Z�nV��������1,��_�~��K.3�L8�����,�W�-D�� ���8"GJ6@�>�M/e�'%�3g
���N;�w�@WBJW�O��MM�W��9
��%�0x*
w��
�<���iX&��(U�x��0���!�"]A��A)������@��� j���Ci�����c��"�n��� y���A�vS�JX0�X���n�4���h.����B����`Z�n�F��'c�,���zg����Q�{g�}e7�������'���6:��'�4�(��{n�nJr}�
����y"t�<
���jV�&��
�#
 er�Hq� ��Rx\_�������Oj��o�q/z�2B����O�w�5��3�p����X�+:�	���vD�����a��L`���������	C5���`��4������|u����R��N��V0���1�<��X��U������������,+ ���m��}��/��#P�
�/c�x�g�	���'W�� �����I[N�Jr*�&�6��
h�%}>��������a��VJ��������k��ZG���h-��w�&`���y������B@2�X?����W9l�'#Fl��8�j3����8���������x��+C�-F[�+xi�C��S��r�������O%�.9c��A�PWQ
OF����KK�����#�����(ku��lD��X��bw��FSL�� ���:�%j?�,i�+�-�[>��'�
�h�#�`�3��>����P��,VFfV�s��Y�T���
�b��M����z8}P��h:��� D���(}����+�����B������5�b4�o5���qp� |2*�`�0������G�d���"����s���b�4���@� ��H�������U{Y�@����rY��?��������ut��0D��p�����E��d�h@�x#��wj���F��4sL#����nPD����T���D��,�>��!��h.��W�O�����8�r�% �6�3�D&/��j��'��N-�d3�d�~���Uwk�3��y��@�����?��������cV_���8�.b7#-��b3B��7���]�V��dk��R��Du���.����B�=��l�Mf4��#�4R��F�hLa�����;Ym���$���=�&J�A�L����vw�����������O��l�"uXL�Q6���C|Hg4���������"����H�y��L�]��.P����0����9B�k���,-z@
8�(�&�))��B���y��8n�&�K����
���G/_D�l>�����(}dJ\\�O�Nw5rJ�DA6xt+��
��9^8<��i���_4%*e�T�w��P����^?~��ZU�����o��PJZd����^���djm����^��\��#�����k��J^��l��H�M�Z�n�����A'G�VML�yF��:������1�6f�*���o�R�����6QIih!I�8�LGCu�l�S� G	�Rq����G{LQ���d'����f�~���8�+f�k���&��Q0����	W��jel���% E���G�����N�v�3�����w�+G.����
�W��d)T�rU*|{��*�����x�95a'�>�	q?����n�j�D7��`*�9b�fxS����a��9d�X�H�y��\�QS�#�����4Eo�I!V���+��
O*OFl��*�b��
����������C��/���x�1a*/��(�
2��)�����9�l�|;����6>�2X�t/��+���aIERg��<U!2G�&4Y�$�Y@9��oFm�J#�T��`!��~�����~ej�8����R������
H���Y�>=>n�t�����!�b,1��"7�xd��R�A���������U�0�����������FR��9�kz��+}����O�@I<wnb���
����@
���-�=�M
S{����U�b4����7��c{J�S������������u�2����	���p���t}�f�t�/f��=rl.��=�#|��H:rN�LOWpM�~v��:�(!�`�:Y�����|+��j��Z�  ��	�������,`�4�u�%p�tXXs�[e�x��Z5]#Ap0������X�U9����K��d�n:���^R_��b��~�1������8L�H7����mi��M��v��z-�$�hl���;k9�P 0[�L�OY���B��>� J�J��q����?����c�&G�A�
�V*<s�p?c��u.�e���u�J(V�rE�3���N�����5Y;�g#!W�������qv.*����{!R�l3�R���N��`-�F:���[�������3���2��A���1h?��<^�>��5��2:e}V(yb�+��HNL������l4K��f��[�J]�b3��^DJ+=�[��Q�!�LUyU�����U�)����]��������"���.o�c�BN��~��GT[rC7!���m�:�>�%��m)�]�?Fs(�V��ek/t5W^%5��`Y�z�����������N��\f�$��q*��.�T:�(R�k|!�7��M%{�bl�����A�r-65�C��(��ao�h\.�1��V$��a�?@���G��{���E�c����W@o��(���!��ei4��h�D�	"�6B]s��uG���4R:]�w��gw>-���Q���aa: �G��*���t���Bvv)�����uZ
��������]���op��+�Y�I�$pn��d�Z��R��U��V�(E6YmI����g�O�I���+�+���q����y��ur.u�+$ 0�G�\�W���^�,re�{a�TH�Q�S)������Z@-7��+Q'W�Z�q��*sV��,T1\g%"=������I�M<�(����Z������qGO>$�{N5�X���t�	�P"�]��D��$�!�y�:������a���s�Xf��@=�g��bT�9��]A���/�(��~����4�U��R���2���]�5�-��8�xITa&��u{nUz�?z�M}-�Fz.z��EC����"�^�'���)yK7�����uh_�-���LQY��)�#2��v��iYU�L���C,����9~�6{�
�!�/j�'�cZ���#��`�?OY0�����	:�`�	�A��'&��[,���P#�"%���es���7r���#oM���-�-F*&�	�V��Zc1y�Z�!#@������0��[�'��\/�J�,@��4������z�)5��L����`/������$~)�k".�/lO����KQ�m���g�����	��V,H����t:�^���c��%Q��&�/��kV�L,B:�5��;��.���
e(�V�]�p�+��U�3p�cm�(�Ot�����)�]������J��!$��u�zQn��Q���R�[���qxT�@�������h�3����w~�b��6&&h�/SFI
���+��&��x[V|2����]���G���|�������G!7���*����������KA��W����R��0���Z�#����h
i��P
��@rL�'$��T0V�@��(Vf_�-9�.r��Dn,�	UN�9��_��K���=|��|��QX���
~4��B�����	�%�k4���d��5��,�������T���$��Yl��X�����!�K#���Y����������es���S��m���c�!lT���4F�����,�v�^w�jE�����D����J:^8���� B����uX��W�G,��*�#V��o^��2@k�t�C�-3Dxn���A7�(�s-�pZ�}
l���S�Do�|��
�:�'5JT��V{LsCUU�X��������<pLptH4��n�"}��S
��u�d.�������e��x&Sk�u�
��F/'=���,�ku����FS�d�IU�g������N^�{��a��m�dU�����
+��NE�������I-��W[s�S�`�Z��Er����p�p���`���F�9�5["H�����
�`���I%��)��g�����5������8����r�L�.�3eL�~�o�ys2����,���$R{*>��x���-�O�B;�c��5�����J��Y���g#S��>���'���G�zS��	���R��f�W�K��D��f����8��(����T�&r�d�`e���J6���YX=���xU,���6E���Fj6��w^��"��F��S2�DWV��~4���D7��jk�1��}�$�X��0��N�!���m'�Z��:hV��2
$c�&���AT�0���7b�D�W��(���@���{�B=������>rG��(XY*�,Ea�t�h�#P�j��	�|[�������xp���{��n��Qn-��qo2�Fm�(�NT�W��WW����J\�hT����[!���I���P;|9�;��H�V��7���A�"��2q���q
���f*���������>����A���)vu���Z����_�R�t��!_�����l<��Ef��1z?e��52P��QFc\���H��r���!QE������A���W�M�=�lK�L�e�d�c|S!�����~�fF�nK���V}�nR?Ci145F:�|#��E�W>s���[@*��&��hAL3�n�]D���v��]D�k��*]��5���ru!EmH*��O�F�����++��GA,�.�XK�+"���!z
M�XfA����2�/?�\^��{���bu)h{�B���*�C��r�������s�v�9���� �n�rA�������V8{����f/�]W7���kk����(B���+3z"�I%����t/���v�2Wd����:�iV7��Y���D u�lN_l-x�Ll�5���/x /d{��Xg���4������I�����]E��}�z��KSnF��g����8���0rF��'0�"-Hk�Fw�����$2��,�F�!f>�������PvU�`��6A�=�T��F�J�p_V*1�������TQ���N�;�'$dX�*�<�Xe�{��2�����+dE"���d�z'���kD�����c���	�8����R���U�#� �����S��B��+�u�x�������"�	�c@:�s+zR�f�
��H�#���v����TM�#(��)�2����T'e�bVTH��gBPH��AOw���R���3/=�(W������A�5��L��T��j��U?�AS�����*$�~�h�����.
�!�~�H�vL=��Q$�N�M=]�\)e�(��}C	He&"@�S�k#�3q<E8��s��0��oV��#�~��m�EStV��6���HSpMG����(�`1�5��j�|����=k����8������}x��QF����;���#���u$���-�jP�rB�B�0(�������\ed1&��>�����$�j�����X�gO���.NQ�!����H����t�73v����9����$�'$�[,�*Ls����Ii�]�=
3���8��P�����K>i9���i�(�5v�f��z(������`N���&�^5���o�N�h��M|��49�A@U�>�f_~3�$/G�TAYUU&PY�Ty7E(U����
���������},|����d�w9}�*��CH0(�h&?l�;�S%
mk��}3�*c�VX�
������t=\2�!=�t��$���Q UH�<���o%��5�����`��\���~FqFv3��Kx�L�c*�|��)�#h�(el�_�L�m}fL��s��sViz���W� %$�������5���3L�TZb��^M��7����5�:���
,�����.�5S�����y�����3�aG��j/(�����xo98����o��j�b��������y�{�(���t�+�4����������'I�b��7+nM������n�?/�r���D ������j���$�fs�
<�X�4��\]^�Y�E�4NaM�X��b��J��8D��
�#��f�����)�� �W����#��~U�5W�c���� w�i��e��JO��;);`�;����v����<�i���N��t`Dg��D���Ln�
+�D�6�I�X��A�]�e-%7�<����.4ekU�+�JO0[c.9R0	�o�4TQe���nHLu�O>��I_��s;T���tT��F�g�k�f�������@��[�����X������.�X��4�� �N/{����Z����Q/j>my��}U�
�����e������J0�;e��-��k�+�I�t�C;
���{\�%���Y������.5c�oe�\)���##�����6�w�:��Ic�ur@�U�^T��Z�Su�����nv�*�w���)�A��8���&,�G##����������bH&M���
�G����A)_�P#�n)-���+�:M��u�"�����Lk�`w��]q�>����
�dbq���8�W!��k�a*�^���
�WK�3��-��M`t��i�:��E�[��dvTS��v��#�k]:e��a���2M���r�RVMw�.)�/6r�?��R%?��F���l�D��de@�`m�j��S�wu���K�w��S*�Q^���e���5M�k#��LD�,tpNf_�WK���u�i��,2�\����'ha��C#lQ���VpQC6��Q��q	�bo5e�>/�9��5K`�v���X��

��<���j��-�F�=+[F���t
���:v���|:�z�5��nM�(���'[�4,��Hi#%
JH8{�9oc�t'���6��UQN\��,�[[3A��C����1�����P=�nQLs����a�h)4Gm�C��C�mi�'��xL��n:ju��,�x��@�`/,�7X�
�
N�sg����b����#g�fO���:|1j�2�ab.����H�4�AJ� �0�V��"��h��%b(�0T��'?�,#�K�C|F���W_�#���Z����:Ti����2����3TT5qoRQY<C���z3Ti>�Y��3���_��3��X������3��j�$����$)|������W*�������:7��?��L�;�ce��'WV</���[:�i��p����.r3�5������`����2��q��]'v��W��/x���J@4�0A-I���f�X�o��X�����!���CzR����
�\;3�[���/����������g�����������������F�p����,5�RZ����]]��\�YPE�O�%��^b�������y�;3},����P&�b��.'��zR�r�^�Ze���7v~��O�MzF��<���5�2�I9�����[c����4�+\Q�����1�����f�a�o�x��<��X���
<,�j�e����9
�E��<C� ��y{�l�/`T�x����r�����gT��>,-
����
����
����_-��."�g��������kB�t��7q:z����.u���Fi���\�44L�g������,�^��)�!�����F���Je�R7��0�����*J�|q1���G� �kSo'������w�rj�(�2)��.����wI�	O����!Y\�lJt�x-@��a�"��Wb�5��$����,!Je"T�W�].�L�Sc��N��x����E�y��������p��g��&PWR�����;���m$La��W
0�
���;$���d����8�
�1^�1��Gt�%\��L��S�&��#r<Z�ZO����L!i��b@�zb������I�^��� �#�'^�s
�vD�����o�?4;o#��������(���
���gY_)��q�xJ4���74��7�!�=[�>��F��>+����aC*5;�	���g	�X�3��|\?i7*����3S�{vZ*]zjIrU��_?��,L���������T	��8�U����Z���.tO�f�]Uj&+};%q//���e��E��e�\���E0J���Xw'��a�����'��uf6�Zt=��B~����c/�B
f���Z8���8������Rz���n���OF��q�0L�|� ���*\J���\��	��{����hu�|$����l���|�'��t���T}�
�~~���0�m��g�����������z�����U���77��������J�>��w�����v�����x�zt~=��)J}�VMzcI21|����8IUg����Xo�g�|��Rs~���E���L.g��V�
��,)iKu��-sC����p���M�4�	N���id5�J��k��������y�+w���zCK�B�������#9e�8�"�	u�AM(w�tv��7��'��l�_�vc����R����h�eu9�U���w*�aA���I���m}v
5���V�/��%�f,�W���gi�����,���4)����;�^mwmm{w#����Y�)����"_[�H������X��f)��9&z2 ��D������_�fjUU�t�}��jQ���~���!0	R0^b�q<9b��;�����6g=P�c�]��������a�9�Bv��Z�ZTO;���NY���h.�Z�R�mV��	9���A�H���46v1h�T���\�)+��d�����q���5`�q�`^(Fe�z���*Z�����q"�A��+�����p/��������qF��������h�<�
�O�J/�����[�w��������������������j-�C5�6�6*;�D�5����qX��?�:�~�a�b��Psmn>�$������t4���}�������E�-�fT�2�"Nko���U�n�v��V�%,��$-��lzF���5T����vt6�A4
���q��`��H�X�g����*���^*�	�V��T74#�k�/��������c5�wZJ�� a�t[S.�+ ,N���JrO��nv�[�Nom-��o�������-!+�	�^��T����/��<���G�����l:����+�,�n���e:���j�XE
���	[�o�`�������z��D/�I�e`�w���e�j?B��k����������=��T���B�����ze#Z���mI��l<��wAy�<~���w�'o��%�������IWc�\���$�vAV����v��b�=X�E��n�]K��{��CtR�Z��E�S��q]�N�����t�������^�S6Uh<���a�Rq-dC/������n[�i�v}��fM���� �8���}5������������$�j�l��B#�������9���z��=����24;f���P�3,�f`�%=���*�.J�p4=cu����g���^�����t64���0�>;�b�����a�
)�����z�������MW��E�	�����8��=�P���n
����	~1�� Z{��P�}����S�`Hi�����WC����K���$f���JA� �T,�����W�m#�o��;�{E��l&�\�*H(�iX���;����j����,���\@o)~�^���?��0��9�Y)20��h����M�7A��]����Q����W���8��#�P/G�Q�Tj��� ��U�U*���!��*|��N�X05�o :&Z�����!���	��`Do������st���_EO@�>���Pu��a�h���c�*��`���[���C�IOK�~M=h���5g$_�� *
����<���"�����r��ypM"����Z"s���:N����&��# �O�KT�99�<����+�^����X^�a�+��x�g��������D�
I�(��������(�5d ��YD��3J�>��5^#"f�A��v����h��_�.��\(jt�T��"�F��h8N�0����p4#�a�f�>�I�����B@Y5!&����������Q��J��|>u�;����	��:�qdXH�g��H��D����O�9j�e��+��p],=�_�#�(��
4aW�*
k���[l�d;��2�_��'{8t<��-��Fg����m�����:�
!!��������k=������)����C�/jK>�_�g��O7���h����d�L�.���6������s9h���,���x�����iPc���R�h�]H U:N�s�&<����tH.PW�)�j�����������5y�Cr%�U��o�U����M��x�;8�'n)��	a��/�-��O��T��`H	R�<"��M�!x-x:��	fY^��L��;�H��^Vy/��b,�%yX����������>������0�
+:EkZ�"gQAi��Df:�,J��{7����y@U�9�B>us���;�c>�dZ��B��R��<X���"�$���`gSNq<`;�����qJ
�W_"�D���t�qo�F�4_�+�7���W!�S�!a���l��f��;�f`(���D���=9�d��nN���W��/QR&��]��
��c<�HT5������L�Wx^�������6�����b(h��r�����u�����L/�
H�]^^#����Y�������s���Y��Gl���M���t%�m�������g�b�D!rj�i@�OYe�Z}p]���P����tZ-�<h�D��2�����4�U���Q<�����g�@v���l���9��)��ta��������z�y>�N1�����EO� -�p�R�����P�C"YHA6������UU�P�_����$�+�:oQ
K}���^����	�u&������H����gc��D��jz�{��y�g��#�ym�P'���%������I��W�}��gP�UQ|gJ���^a
��9����&��h������su�����P��~������r���G�=�B���p�3f����|������_������!��
a��x�|����4�9���D��x(����l���h|�����%4��0��A-l6�q�y�i��h�,Q�t�|20:6��*���Y]�T�v��G���z�
r~�J.�eT��,S��n���Q�l+�J�/��|F�Y�$���Rch�w�����*1������{��Q��>_%��K�����!�<�9��"�2~a���Q�l
y�L��%�����1.�����0��^�r�WYv���'w����Va�1�Dm��Z�d����]����>`�b��\�i��}�F��+>&�OCS�����`:M@[�������JU����J�V�
��](u|��N �)#0$����?/v�)��4nu���(��*nI����^V��	y��������J��e���(���	P��f��I�5u����~�����'�RQ	Z}��W������BI�zq�@�D�x9�-�$�w8�m�QL�M�ZvC��-���e.��U�S�~R����JJ4�k�V��3�������Z���@�4G�7^�_��&h�32yvz����Q+��E�~�Vvz���M4\^��*����0�U��&U�y���o(���`�_
��8�o�����C!���4���2���G��`�+�&Z�$�R|Y�H7�T�Yr]'^��������s�#�Uh?�[E�����V�Y>�^��`����F
��i��(�6j���@v��w�o�}_��C *Jm���O�p_���;�����c����>wZ'�E�u����m�c�e���=j���]K��T��M�'R��%�Gb$���lc��l��F�[Q��	%hB�f�j�����D���g8�D?T��^yO��/Ko�%�1��/��>����}��o)�@�3.�����R�q����%�����[*0"����K`�G*�"E���Y7�\E�YtNM�����
��Z9Y�Qj>��dz-�r�v��J#q���mT�u�%�	d��`��8=��Lm���k>���'�)�"e������������kL��	
J�������y�����ne������;H/� ����y�� �s�Z����&�����s+������LNI�����������=�rW;S�c�")��y�"C����_����(����!��a_Z
R�G�AN���Y�8�����5Dc�=������H��vl�����:�lY��W�
sm�,t�������8���o}_?l�;v�]C�\��rjWz��S2�sJ�~�V+�f�``{ �>U<�x�V��MlI��Y�����.&�VNI4���?��&�Oq�.H�CJ!}��N�M����.qm@�M���+ciK)����
���rF�`������7L��F^�B������l�w6GS�Xq**����2�" #�(�Y��@�)��*�#��t��]=>:�K=>��;Pls���(8p�r���L�.��� a:/c�Z�����H���fP~2��Y��R.�����5I5Q,X//$����;t��m����~��]����R�R�|x
VN@���&�{�K�
=��c��Q�P����E���{��M���Vw������/O����g+��,�n�
�0�e�\�4���E����w��������������[����G}[�[o����m���Q��m��*�d��6Y�n\_`?����������IWI
0��*A��L4��f���H�������?��o�n����*�=�iwnw���&3b5�w�1��@�xI eZ+��# �jriJ�zb�C!�-�&7�exEL��Vu��*)�B�?��M�����G	X��l������^\\��v�����RI|�2�f�:�JPFGI�	
��
O����p�(.L���h��|Jf���0/%q�7un�]� {$zG�k������`=��H��7�&JY�����rRs�j��_�}�0
��o\��Su�l�d�<��>8�);���>sM��g�cd������h$D8"������X��#��/�AbC�����#[k�QH����w~�K��>�
���w����h����p�
��\�k��`/���+#Gb��4�?)��:�<A�g��lc{�g�����k��W���p	��
����w�K�~�B�Zi��/��(��^�y��YS�6��p���t�
��PL���p�"T?����J)���,A+�=
Z��CZ&����������BW���+n""�Z�ZP�rD.�g����fF�"���Kn��Jm������?������A�c���&��R,X�#Kyl��YI14+)�uq��dgV8�U��AIC��I��p��q8+^�A��2��J���JTvl����eu]0���ol�g�����'|7���_���\�C���)�mQF�jg���isG6>d��o��3����e�P�Z4+Z�������U`���R<E&St���Ye�6`�9B�Zdsk��P��8����J��=�1�@�Q���E��I����$H�s��BD1�I�U4��noB��8�����d�����@D����
f���x�1�m������[���m�<�D�`c���Kp�������v��]}�njrO^e��L4,%3��* �]'
s��t>����H�����~��^�[&�[4�G���j�S5�l����w�BUe[��~�R���T�*21����^�E�,�l��(V�������$S�X�\{�+�����h��0��Tbg�f�jnS5��ue'�F9Awnl��5N;��\�$@
$�~#���hG��o�MR�Lx����2+8 =��D��:[�8���I���/����%�'�N���3�G+�;>�_�.�|��`!�MI�ZO5�5�������R��E�����ad�P����1=�VSIdI�o-�
_FN����t@��3��L�F�)d	I��T��L~-�/�^{�'���OGM����e$������Dx��'Cn�'�o���q���C|��E��H������!�m�V��>��o��z�1������Jj����X������fG����p�
���9�d���%`��K���R��`p��F�m["�C�)VA�]�70t�w���h�%R24�$�t``W���+�1t��[]y=W���%J?	�A������q��"u�O�4�^��kH�9���08���������R����AK@���+N���b����]�l�����hg$��M� ����WV3��j��&�d����K
j��"Q������H�s���j;2����2P;�w;��z���;��F�������@��j�s�?����
�������v�h��~�x}����<�G}SA���W�a<�����p��/�.�	���`���$}�'P�9������o%����ur3o@B
#[/1��C���U���	��G#��&�T��=L.4��{BA?,������V����
M�����^�68��E����{x�WN|������V:��v���(��I����u�)U1���
:�Y:���T�3�3��
v��g���?����V�1��<h��Yr����q{��0��F�b��r���Cm��C��������Y,�y���S������o{�bLp��i��H���8��S���CE]�&>���6z�z��4t}��^�
�o��DL7A�5O�=��*O��i�
�-���6���}��iN�)`����	Y���<�R��T4�~�pd��H��,-����b2j5o'!�_���@�8u%�������9���;i��c`e���b�@����}\�C�y��[��5��=���#+Q9��4v_J��}J�*.���Ec�����������HOP\��H�Tq����-��!��&O��=v�$�8{K�O������#�e��R�s<����#�p���Rq6�pb��@���ms���� �V��K�LP@�P�)-����v��y���D���y�sJ��$=�Qr�w`�^0��}�R��}���M(4��?�_�(���Ir}R]�X�O����c�T��p�����
|'�"g��fhv�����#��	������w��q��8>:�;���g�0�ld(�+�����5#wf�}�r�v�G�������(���P�m��������W��
$6���qlz&CS�1p3�Xfw^��[��f�cEX�B1���\f(!�z1�~L���*���]�y�5��(��Y+�_g�����w��CHU����"���#f|i9^���h���'���6q6t���,M
qL�=^�l�Hq�#)#_D��������%{U���H��h�S���^��vwm
���������]�qu���8]A�|�\���H�A%��^u_5�4�
���HW�2��{/��"8�.��"�i��V	�mw�����8
v��z���b�fs_Q!�+
�]D��52��Vw+[U�[�^��o��r�Z<�/Nl?(�(�l�����E�"j��~�W��7SeH�x Yb����d�)~���5���/26(m�����{�*5��6���Un<�W�����"���[�!e_�kL�W�T�U8��M�~���}_l�juc�B�T����?&���XD��)a�Z���l`P��Z���7���K����3[����������g�r.U���/d6hv�_���_����>���D�E�;�/d���1������n���
�}+�����n��G�$c
��g�eaA�9U�e�m��W\j���w��Lk�z�uHs�����qs����@R�Z������20��#]�����K"��]�a3V����,)�E�h]���;����K��K�����[[�����B���8�8:p1<���q�9d��sR���O���������}�j������^ek�������"\1��kS��oS�>������t��m��������y�i040��i��nN��8,y
c���ND����I��@Gn� ����Q1
�����Za0���4��
��Yz���1$]��<�D��	�h�n��mukKf)|G��)�Y�������G=��y���'cS��o���5l�}�yl��X�Q�)�/��Q�T��`E*�;�jk�Z��V������G���z�c�nH����\���q-��������S���E���-���7�h�X����N�����FB�T�����������S����%<��G�H_;��7�!]���x{w�R�,�"���C��Z�E��!�EC��o�.stVX4f���k��\�-ugc�E�b	C��Q�i�s���z��m=��,���`��|���C�cg�2)��^���2��'�������j/R��\_s�����=
�#�������e�^_R��Y�u��
�H2�hK�Ws�h�725i�p������T��V�=������#�?Q��a����%z~Q32�W�z`�n������l� �X^��nz����>i���)y.���IZ[l}wGP�����W���.������}R�k��L�J2�iMb� FG�
�n7.��
�(�q��E���"�Vh����(nX��3�.��d���v*�/�B����y���)^��z��]��K��"c���k5�@�^�{���@�����
�[�a��X�]�:j��[��h�V�mU���w6������
W]!&�d�v����1��D����F*#�=%��X�D~y��7�j��I��
9`�(�j��\�+��cq��aokpT$�=�.�4d�z�l���F3*;���Yj�G�u�<@��"Ph���E�@���P�kW���Y<9�������x67v��hU&	��j��z:WB�B��:����J0�N���������\9i�:�f�����OJ�Xkvm~E?j���V&"��t�Ofh\��IF�en�sk:��*ikhSa=�^�4J��J�v�V����o�2lw��h�����>Z����+�t0���[�$]&����B.rW��d}r�f���2q���:��c�/:=�&O�#�cd��&��X/:��V����H	�V#�
��Q
���u~��^�J�{kFwv����z����vug�Y�[5����*��/��ooX>8�{>���^B�����L���g���3���J<�X���:�Z��S����r;2�9��z>;w������`K��2���h%��\������4*31�'o���%!K����!�C<J�$�%]����8�6�+��{��Xl QV���A��%���fi��hA��g��]�G����f���hu�L�4������KK�`{L����/�0�!Y	�����$�H��f����fG���l������R����8�.
�l��b�9u���$��Q���xX���>HqPXd)~4o��>&�[����-4����.
w����$���'�������BDb�F���,�����E)�����i )�/z���2�Tp��"����*��W`�/	�?T�D1���LV"O	���fi�W`��	l�"/���`%�����Q���|q�n�h��D��~��^7��su���B�8
7���,U�2�4�n���k�������O��
�>l~d��v%�4g�W�	��t�@��Y�	�D �\������p��1��
�Jz�_���@FJ]}���rQ�IC(�(~l�wj��gkk�;�[���xk�(?���cU=��@2�j�����1���5�~2{9�(lk?���K%�P!�}'�K >]w_�/Jl_���d�5��f7�>aa�{v3!]�����(@�]X�����S.yj_,�3w����!��\�C���Tz�z�������&K#8,-��	����a
"e�8�K�G#�U�x�4@��&�8������@~�
)PFi�6[��)m:��E��K�0�O��F�@1m��C�Px'���\"sc�����j����dLr����x>�~�?.�CE�#yx?�JU����%��&�='8(��>$� J� 	:N��J�im� ���]J���j�nz1vd�}���dx�F9T�X����J}VC����i��
��$��x~|\R�VJ
�`l��TTX)�����[]��X�2y�<R����H��EJe��Jr�K�'�g3�34s�P��^a��*��>��W���:�����jDb��T��#���6H*_5�d�U�C<0m�S.�D�����J��M�[����lZ"������'Q�/M��W���;/"���dW���;I>UL�RKK>�{SD�A�2��K����2��VYomol��zk{w�R�#R�Og�2mE�I� <��a�#Q��w���h1����V����SmE�U�+#�l���d/y���,H*N��Wt��H:U(���(_u��by�O�v/M���P���z����H��W�mmn��jkkg����`/lUAN6����j���A�Y9a�����1Y��H����h��Z�!*y
_#i�E#�p}�I��J�&2��]<HB8e(T	06����Jm[z-\	��_���f�+o�������Q����v��|Z����-Z]n��<@���zp�<C���u��f+��p59Q���e�C*���
cX��$q��0C+�����g�F���:�!�o�U��b�e�Pm���}�~A��o����vW`��%];}�l��9����ug��%��-���	���(!��So65	V��`��F��������+`-z��$�,
��f*<R�h���lN=��b����p��C<�W�9��2
���*�x4�oTg6�m =g�u'���>#�SkPR��L��b����������?���Q�_"S� ��\��co:����h{���u+��������N7��l�6Xk6:��3�^����IBe��PM+
N�H����&���2������}����D)����� ����m���(����������@F���y	Q����2�a��*��7#R��I����\��{��-
�KK���zaTh��B>�E���`���~,�Ap����q����z��b�Bh��h�BPWDP�G��y�TNZ���-�(�h'D�FnZ�X:�>���Z�
G
���K��J$��y5J�<�.�T=�FR�4|
�i��:�d6�CApp��_�����D���������XEK
r��������F;����)�w����$��M:�V��W��U���Nj�-�3���t�yz(�V���Y�(���y����������� �^�cN����x��Ivdn���?4���d�[��������+�Hu�<�e���'��zF
v�a�S~��V�[��������p�R)��`�W�({U�|��t'�s�H���AS�n?n|$�A��������S�����6y��U}2��r6V}�T��3�kg��>95�n8/�A ��n�"`����e�{.����<���12~x2�+C4A���Ki.
9RD��
�SC�I!��ri�$�>�k42'�o�P�f�|��=���"E������'��7ou�,�u7P����(�5���(���I�����z2L��'�^�k���t Ik������&}J|y5�v�.���{��� ��^��ss;	�X!2�&�H�����6$�QG��	�K�;��$\����qR3��i�%%O��TC�K0Gz�Qt������Q��������w(��?&����9���~��'����I|Y�������W�p`K�"�A���MH �Gw��!s{[R��
�Q':#�:���c����;<����`��L�O�Z��T��7��3���@e"�g��$��&tW�K����@��0�>���F�r�����z<�:��~<��r0��2#�-�U-
� �e�y�xx�KDbB^�+���B��R�+����-smT���1��BE0�:&bL��F[e�c�"u\A���E%��h��o%�r�����<�i��pM5+��u}�{�"���"���T����X}y��2��2���y�=��Hf%��a,�o����G�^�nC�>�5G�\/����(���xP��B����;��^|������������{g�En+T{E�,T]���nc���ddy%vY����	�3��X��4�����D!���X����*v�@�����gG�ra��qO�1<7�3As���y2�������xp�I	�Ia@�����c��p�T"+=5:I��������'�>��������m+~��Y�%8�L�_�.e{M^ye�7W����n�td����r����ele�cLaQK2@�%��!�wt5+8����!��1�q������i,U�����a����H��	�3!]�%�hVN�/�����)��	���8���E+�U�JRTa.�>��_��w�������a�)R#q���J;��ED�CD]���lw��X��'+V��+���h���6�+�u'9��(��������!�d��P(��s	���C��Si�X7J��1B�P��(�o�x�:_)�������
���<�5F���K�9
:���������+��-�E�R�C��xHC$�U�C7pQ����_���'�����_m�R^�UyVy��j��)��3�����12N�I��QVqt0�&F��	�1��bYRC�th�/s,����g�|CH���'�F�����:~_���:UreB?ll�C���N
�Bx\|(�#gQ0>:u�d��!������Y���z��0��g7&d���w���9�dB����}O����b�_V_��l�=_���>�@#*>J�nY9xl����f�d���m���2�M���`��gW34�W�<����x'�	������q5�0���zh���V#{5���#�!�|(�G/_�����Y
�2=_74'���Z����Q�R�6�W �TsQN[T�}��r1��d��_%�IH��^�D���I)��3�.���q��������,��g��+��
*��K��N����/:�����������oHM�}�U���Zn|�LG��	e����_�1�B1�y��~��IP�9�('U(���~���7\��Sa}��������.�p�	��&J���P�����(�J���uI�\L��C�u�!���=S�*���mz�.�7y��
�	�f�~O���^����~IE����]���;���t�Qs=��i���I5����{A�h�S#Z�}���G�Pl)��>���u(�C9��oQ-z���'Q5ZQ���X�T�d5m�J���a��/*�0�i"��&s-�V���m�t7�T�� >�H��G2Mu]�����LG�#�3mZd"sx��-0�n�,M�	����J*��s��R��2����d�<��0�������+��P��oU6k��Fe{���rx^L��4�R���X`w�N���TJ�&��Q�A]&H�/�6|�"@�gM��K���KgC�����K-�roI����5��P��4j)�a(�I�+-4�zj�a�S\���i5�:u!��������QCEH�C���q�|��Im3����|Y������l9P[�P��I<7`�Ll������U����(��K���R�`1�8W��u���/�\��'�"<���G�C98�1_�,]�oM4�UCp�-�B�����A�E�
i���a^�v�����r����#wo0�x���k���8�x���xD��+��P��`T�X�2:����J�Q
�bO��M�����@�W��*6�#�g`5[J{��|B��:��q��b��$c�C�VoI�V�N�hB��;�!�cR��~~)ec|�G��YX[PZa@ZQ�5����@_ WMv�_����:�!eT�������7U������[���61��b1(s)�R�����*�
�r��k���r�m���'HY�4����Wd��ZY�]�����n9�
��1�:O~?N�D�3�z�:/��n@��\����?f����v���-�fj�bz��r2O�~��r%z�=J����F��,� ���+��
�U�Ob�$N�Th�fhLk
��^�[���0�����
� 8��3�h�E��S�B#��"j��p�OP���e���
��C,`]�
�,����i[�����n��n�t�����{�R�!�@��:g-�Q�i��7X�_}�O0~%���['00�GtJ:�l[�G�!k��X������X�GPd_EL�����$������Qc�N��[GMP����
*���,_
vBZ�7�:�����T!�d�u"
�#�i������{��+d[T��-��"��3����������T��Q
5+��q'�4��^�T�]!I�]������������qH������P�>�)C:�������{���a-�����l��>H���1��+�/��.�)-C������'����I4c@wq���helOw-'1D�H��!R��YD����"�!�L
��o�u:pRm	
�:$�yP�$�@Z���q�?����?�q������T�6G]���
>d � ;XPN�pO$�����������������T�J'Q1|~�O|%uv���%��2ac�s�Y|���lz�(Tt������I��w^3�r��)$7����B=,#� J�A�:cN%{M�	(#O��i<d�sU��;��K���4�NpP����e9��L+w^|E����*[;�28�P��M�'>��*�>������?:}�8i��2<�I��o�y��n��[�����?��`G�w�h�`G�w�h�HG�[�;�	S�vv�yQ��"�u?vTW��������I��b�BiK���\t��b������<�=��~?��C�3M�6r�<���R�S����
R
8*�3�� :TK|	V�������i�1��P���$��L�K��c!����K�(�A��3��X�0rt����	dN�/�Hy�����\J#I6}��L��A�BP2�ci+�!CRs�G����|����������}�^&����V�!�-h�EtZf�,HW�����HP��+��D�U�3��g�r�����d|c����ox���e���O�����XP��F�T*��i|m�1?���f��e�0�:*���0��j[������Ymkgs��]�}���������	��=a�	�&#�]��[���v~=�>�H��lp�
����}k��$��[z������x��rqs�mn��?�q|P���4�
FS��W�00�=�
cJi����Yq�Pu�#�����Y���t�uL��
%sd s�ngc�Y�q�R'`�3�)j�~7 �����]{��E��KV=Je���B�E;���W�!��Vd�xC�(e�X�J'��t<F�����6�@�.���JO�������*nr�����x4�H(���������� B�b����+�	���aw!\6���]_IK+lP���-*��Im���?0�����`�+�e�V�O�U=UV��Q�B��`��Kj���Y�GaJy�94C�;�����^�0����(*�������an"`:���4N���A�����-Z����]�+ h���,KWCL�L����O����l�O������<�]�)`�w|��t��Q�8*)T0F`�� `S%�c�]�F����g�S��8z���y�{?�k�x����A���<�,U������L�x�%"���c�
vdR���]��g��q��HT�X���&���Y<����(
em!��x��'f���4���	���LeK�<�*D@x�A�JkketI�Z[�Y�Pq�uv��;;�dWx?�M'N�|��H��>>�,���o��D;������������ie&H�&�����]���d��������E�����
��8~��v�	�+�w�#8�P#�h�AxbU�
R�p���$�m���w��M��|�,?
�/���f�!Z�A���a![��'�W4�j�����>�I���8�.�
�6�%���-<Xw� Qe��T�-#d,�e�oh��cR�����C]G�V���zV&%�X6NK=z���s���@�Y#H�H:w8Y�E�#V]w�Z���KK�\v�������;Ki����X�8�	1j��^yB�TG��0�P����Iw���xW���~z�aZn����Sx*X���Q~���j/GTD�5�%��2��P
�� �}�M7����I��V]�T�V^�VN;�����1�/l��5����,�
.�Rb~���A��M��d��v���AZQ��('�T����e#�n�d��D��c{�Nch���t%	b��Pp�M��1�t��G<u.b)@��������~Q�{w�v9Mw�XTEv�x���>��Iv�W�~Hh��\E�u�8{����$��S�Vp{��������i$E�W�G�D=��0"K��&��*�}��
�{����	0�����l'W�	j���:5����.cp�IL�z��6�{�O?�6�M��wo�bS�rM�xw�y�~tNN����a[�8=�������R����Gd���IZ�����8S������Arp�|!��M�J��,+�����gd���^��������i��rxf*=���������u^���yUn'�j���[���=��H�H1)���N"O#�o(�RF/eFFY��i��O�]�����N{-���>K���C�k�<�7��#�������C��5�w�Q�#�|���{M�/�9����
vi�hu�Nqz9��+)�A�]�����i����~�����CWK&/j_����cD]f��!��t���+�����#c+��M��@R[���a���)>u��.�:J{��7��mAz����QT� !��5��a����1���'t+�
[�������L�.�.?��%u`s�+�+"+ `��e�����i^����� Y���WK���&rT^-�R�V���G��0���+��
	���B'��������;�^nwu�I�nK����
i�������Z6�I+�����7�X���i^�g^�}�$:pc���S�N��"��0���'b�]�}�����d�q�M�%I�?��[�b`���}tRu���:�����c��2QA5���Mc�bM���@��B���~:.(�X�C���:�LrA��������]���/%�I��,�������,�-��=;�i����z�
r6����� ����5�,���	��.Ip������&��qcZJ��>�Y������C���:��J��������9�n����}��3u�Y)�[�H�JA�n�}�fE���(2�I�id�$�������*'�7��-Q���:�Ty���e?�6�<���YW4�`)��{��Z��|�����c?�~L��[�s1^�_8�M�����1����C���/��/���kxy	�A��+���������p!�������8����JuG�t{}�R]����������I���e�'�/�����dj�	FX�
��/{�$�����T�_�`��a,����y��o���N���_�GPa��JI��sW�����V+8(JjH�����
�]�t�2�%81��iZb��+�\�B���S��]F)E��m���v��H��
�q(�%k1�|�O����yI	�
�����srg��%$���Z�]X�v����!�1���f�������i�4���Fa�����M�)��6���T$d�����is��P��l�6�
��F{��T��*��p�i�=�����f�g�N���kR��%�%aAW���U�{`UU�Pj�{��b�;���8�a���
*O�l��Q�B��- ^^>CvUq)YDS�h�/��^���C�B8�������X���0/k� E�_��@���&��N�u�U�{��������Vy#%Y�I?��+����Lg����7������gh4N�;�z%����Y����>)hV�A-�FC@��9q�1/���?b���M�-y"�JI�Z�����,����`������t���?�+c��9f�#]_�=��^�+A��������,��o�T�-�I?	�M�$"k�^"�Z<.J��+""{��t,K�o�
�T(E�`e�A��U��@v����K��g�)8�a����iG��to����V������S�E��A�~IgS�����fj�2�g2��/{����x@���V3H5��d��(0�����1����p����0T*�'�<��LFc��P�y _�#�@���#qn���\6!s���]���+����A��q 8�oU��esls�vv6@P��fY��pq����p=��l�:[��6ZY�C�`XTM��=�D��ytB#�M����{����������p�C��R'�R��+=Y�Y~5p�(��G�`�a�nf���{�������
P�0��'� ��=���w7��*��S&�y�3u����7�����u��n����N�$*��V��hYOu��1��{2,���ZLE����=>;��������a����06�ZJ1(&D��S��{y����H,&������h;a���E�����!W�X9Cl�34���D7���C���`$�Z1I3p|�E=�{UH�"PbC�B�!QO��7�0���	#Ud6�F�i�s���=��;�)~8��C�4Vb�=�L���7����,�7��r����e/}S��c��tB`��NeC�!�	z��T��,�5���V_�!�!�Df��sC�o�~.���v660�H�1��Z�\�M]D)�,���/�L��?Go(
��x6]����x�3�����6�����O��P�0C��l��������&�R
R
����(,?�rD���X4;,�2T���P�zq.$��2����F?�����E���>|M3��>&�nT���lG�c����%J~w�����%e�����*�NYc0���Llu���U����L��/��&D�Ra�K�SF.gg�b��?�/��+q�S���Q���7��-"�e�`4�����y�������C�'��J����%.G���u�`�u�*4r�2�������t�F�	v����C
���6Q�bj��z2�g���k�	9v)�E3�r�I�a7rN���Q2�h
�X�Xe�l
���xwmm{W�[{q^��L(B�B��xT�!�7��������B1#��8Y0<�e|Iq+��!�� ��#Di2Q"�� ` B��y6�pr})��g7��x>�a\�Ke���=8^ g���4��N;��}
vT1�v o�lQp@�P �9����>*�V�W��U��
:i����,�ax��!��i�H�������F!
v�)F��F���	T�1��g1�$O�:�v����
�\���uYJL���>D
:i7:�h���������"���?l6�:�cax��tzUZn��DH��yt<M��^
x��o�8�K�lCT`�{pO����	u�TS��@�J(@��pI��Q]��N?V[�]Y�/`e��zGN���B|�Fx�F1|���
6,�
&����*�/�(^	��2�d������cuQ�^���Q���%=X�0������_���m��������.|��rs�g��I>�����8�ZWU�U-�S���,1����G�3���+���$�B����p�73��3AA��b���_�y�������K/�$�O�|'.�Z���-��WMl���Vo�V���
w{�����p+�T������g�v��V�sc[.
��A�k�nb�/���y}�7P�2��+>��C�2(�J�!k�.�E�T�q{1�B����
l4+w��e�T��
�{'�v�NK kx��>f�`�j=����~3X.2X��o2����y������/���;C���c��,�b��$o������B����S����@sv���4�b�7���6�_t���������
�
!C���P��S}%�m�.��qw(80�����H��2����TL�'s5���UC�/���Z;����[[���z����Z!�E�����Z����E��'w�2��(U�����@�(���*g���������v�x�!u�E����U��&�L�c�(�Vq�����}�`�_`jF|mD��RSJx��������r�y����I�f5����f��q7�����l������-��wj�Nj2���bu�����Jm;�E�{wBJ�@j�x�A�^_^�x��^������R�H�ec_���F���f�+��nw=�pD�s��oi}��'7����x��^��[������~1Hx�OxXi�l+��,�� ��������"�t)�W_
�]^�������<�(�����V��:�,�����H��,���
�R��d
A�q�����]�������������1
YDX
	t���O
8���[!��AD�z�?����9Q
����={��G���>Ef;�M/�"|�Y���������}#� ������E���h��LB^?�����N��m�R�������crQ���>3����
�nT?��x�K��[���N��797}�����[+&�����
MC���}��33w���|��]��^�����@��;�4�5M�����o-����B,}���`Ik��
,�D�������i%�}��O�4����^ ;�����|�m�KVkk�R�Z�R��I�����~�eI�������&����zB���p�AG�<�8	�w���w��|���������	.���������x�u$�����,�]8����:���9�����������{{����Y�:��R�:�W�g
�gM��A����so�����iO��������lp=��HG>��� �x{�����u_���j.�$>k�><�,��D%�|N����>���W_�A^����,�b
s0�N<���
�q
"�����g8,�����7T<�L#�,��%Q�'HW���(��^��&y�z�3��U�l]=����q��I���y���z�����A��Y����a�:�7{������S���dH9�b������Y�Oe�Xf�@^1z��y�K�7o����>d����*2u �>oo���9z���)�r��s�(���3t]\���!���A\�"�te2��8�J��I�����d�N�H�Q(���e?z����9�azn�W��43��=��n�S<yfN�����_�����9N����0TH�d������J���B�����H���?��F�g��G�	j
�����,�X����gmn�F���+���e�4�iW6EI���L*�do6�c��C�1_��������`��Y�\���qf��h4��n
CsD�l4a
^�'kt�lB!������x��Z&j����KH�4���-�%�H�k?�:p�:���Z��������YaW%���t����t
_uk�zPQ<B>,m�3\Q�?G��:��Y����)OA4W��3���-�P�4`Z�6�F{�����B��G�]��2��F;`@\w<�R`@L8���r��U���i�^F��Uk�[\���j��7�\�f�-�� ��dS(,c��5�rB5����xM����Iu����8���/+@���Y�C�P^��d�� o�����|]��b^���Eg)Tq_��9���� ?5L��?\=W�B�6s�r���Z����-J��	])���,m��|�u�B�9���J)�[h���1�u��*N�SH�����7�����m�1=
��(�w��Ik������L����U�+�y�z�.��&�/���������B'�p���D%�����-?�s��e�pb��C�26 �cly�f���7�;�gKHK+��6�{�*���F%�S>Z/r& �u/�h.�^8O�/�n��56K�Q*����:�Y�+<]�2��k�A_gU��o@�v)��d������yJ��YiN&m�����c.,�w����_c7���F������f���m(��S���?��e*!}��J~��2�U�F��������2C��,s)�k��8�-��r�Y0�w069v6�d<�"�Z0��@>���-�������k�t��I��#���F|)!)*.���i�ohY>�`���)1Lu�0~���e]��h��l_TN1����H��O�^��|�~�A;	"����[��g�7���B�2��FU�l�%SnN�n�e�jKb�B,
k��f�C�J�����{���P&��5-�3���C���s�����Swk�����D�[��Wy��c�j����9:%C'����Y���x�E���p)SR����ma@E-��lK���;�^�"hA
�J@�q���SD�������=�Oz�����P�K���[a3q���F���H���e��+� V����|�����G�������6�oaP�7�Vw,Gi#�[�M:���q�Q��������i��5v-C	#i	��daek�c�V�������fZ���Sla���w���b������o���JM=�ta�J*���0�+RX�wBD�������b$��otQ-��xo����)�KS��o����i9��e���4��1G0@�����_2f�!��#2�����������*�y�T����P�K����_'|�Lb�S[���x#ci�
��>#���}���zd'	�H6���J�*��	3�k]_�/���y�k�}��9���T��35�;�4�J[�zs�2a���a����g�J�YJ��%n�m�Vn`�'�[.6b��7��d�r5R������Q��!R�%�zB�&�2y��j���q��A�����#�g����9bcl88�O��Z�@���9q�3D�b��sD(cm�-P`��dp��_�.���]����X�r�|�Y;�����A����K}�z�����������&rG����X���Hf7B���	�51nsah�>����i�������Qc�m�lh�Fsl��L��MFD�=
�4;��$��/M�[x|"T!���PWmlI���/��z�=���ZL����K�B[�U�d�-�*���jT�s�p������&���r89�Br@�Y�
E����6��n���+���<A�	��y���9(�P��5��>�V�{��Sa�a#bAh�7a���;��h��_(Q6
�������6}�B{�T|>���B�u���<v��S�)A���&Rf>wW��<����5b{JD�kR�*���)q(yb���$N�4�a�q�ff���G=��������%�L�6"�5����p3���|K���j��I�3���_9���$_Iqr�m��RW&��{BB{F�l�N���-�K���r'��k*��@�0\��m&"��d3�(��K���_���{<k0Y�6P0+#���!�.�pCM^g��$T��<��d�=
%���(5�,8�DXi���*�6A���_��p���s6��;b���$�z;Y	�<D��b�q��*"v��x&�*&�]�I����0�@c��������/��bbf>H:'��"x���F}e(R0��u��q8JoQm�4�d�C���co�|�P�s6�F:��Z�>��&T6�8�d�#v�l��&*�z��,�d7�0UJK��>��=��D-�\�T��f"�M����sk#12���Q�,���3��/z�Tk�L��Y�4{����?�J1T4B�)9���Iy����D�r�

$�r���������������.����gq�[�(��-r��)�)�e��q��	S�4���^	���^�����s��,2+~�*��d�S��I�!~Iwf3��/�^������W��O���;���y��c_��c��y��ZO��'�w>�U�~�rV�CP���S�NK;(48��Z<�(�(%�-��1�|�Oe�����/�K-=Eh�����;��f�]vOuA i��������mK�+�o��{Ym9F1>�0��������b���}��asu��~<��\t/-��P�:m�|Z#�������������\)��`���!4�^�6�X���M������WC�z�(��o�����������s\�s�%3�;�����](d�����<�wk���x�)3%]U60'�'�����4���=
����A�18���/�Jw��M��r���0��(��
�/��C�4�
�����j�.E�p(�B����L��5�Ddw�/|���/��#�����7=��#o_5��1�o;�w��;	�IBM�H�O�+���o}����a:y���5���,��a+��h~?�t;<���Yu��C���|u�1_~���/��*m��+Ej�8�R���u����Y������SO,��'���=��.��)}'�,���h4�K8��F\r#<�i�*e,7_�o���5����
e�t���s�[#��}�Z�e4^��4&��hUQ�����������,�U ����3��5�^g��89�4�ZKy��7��lP:��X��E���7���/��i�O��t��[�,<_5=%7�>���a(��<0{���Y���T��MJ9w�Z$,#Y�������&{Z��W��LG4�����d��
�'������5k?����4�7l���xd����P��gf�NV��gS9��~��s��i����{���4 >�0���2!/�%��
�B1!O��t	�'T+Bi���`��j�$1�*�/�b���b�"-v��tO�=
�P�- 
�.��v�gv ���A���$�oj�Z$�r����h�JRv�t�:?Al�|a((��eh%�U:����_h�i�8M�9����)�s�k'�H����;��@���l��k���������|�C'\_�w�1%���;�t�n�D!03��������r6�(S=���t����o26#�om+E6����)7����4+�4����H�������[��W�����9�aDk�z���o7���G_��Oq�Bwie��,dd)��c����4ik�5[�����7mc�S�"hE����%�/-.�*���l4��B��`��Y����V�P�Eq~s�r����}oS��F&/M�U��jD%���|�X	hz�c�p�/>��`X��Z��.���������4��v���p���~w=��W�RR6S�j	n!l��`&�ym���4����"G�W���y~���k�B���|��W���J���.�>T�H���T�@�1�g��!{ /�3�]��f����\�}�}�w�{�z���I^(5����:/��Hz������y��\5�[W�����#bu��v��������������>=0a�����V���6������a���6����q�}+<cg��`�
�M�2;�	���g1����wv��:��������b�z�i�m�A&�w�S��������F���������o�"�����\�/���b���tZ��T��K%��T=��*6!��[o���{{~�}U�����u��������j^��Zs@�[p
�d�!��AE<r����K�ju�����#:�a}��e+@�~���l�����g���c����y7�P���x��
���h^����H�F�]�]��<�WX�_���8|5��R;�s���(��p����U����>;��������u�>����<Q��NT��~����H���o�Y���0���f/+�������j����^bAX��~����/�kb�O��"��1 MAlh���i�4����If,grk��!��/�)T�g��y����RSa���R�b�rm��>�;�`��_g���?�C����
�E�:f���>�
�a���B��@��
�
���']N���Dmt���^>��X����$X��bV�.Q�e���l����;�o����30�b�����"���3�*+�jt�\��\�����CU����Ys:�w��YQ������c{2&{I�[7������'�n��U�*U��Vp[
e��uK�> x�3���X��F'w�^��V���u�{���3"A@���9���Y�c�j�3^���ed���&
LI�,U�rV�!�����6��]�.Pm���*U��3�y���"!�����(!���R��.@v���eF�����UVt�G%� X���������X��d��Qn��z0���.�~�z�|P�@U���`�^����u���`p�h8��bx@�-������mV�DV_p����G�gV�)���0�Y�a:���f�	��\gV��Y_��\�j��� ��0<��\�ZA�f�c����'��~��m����A����[�!����y��s��@���
�A�6���ptc�y�4k�t��m�����������$�������N�]�1	����-8%���D�aI�2n�5��r�P����{:�����=/�)Df ��)��7��Nc���
��x3�������?<�_./�.�b����%��M�-�/���������"*��:�,g�O�:��������N ����Yx���	�V�&�t�����l�h.#����	��S- &p��r��5���)���gW���9��;�+:������#��H,=����u�2/�����i��G��[X����		��F���PV����0��16�%H$���q���7a-�'^g#w\l��E�P�N����;K�y2@$�?F�?4"�[��i�7\�y2����_��t��	P�~P���3~>U�r�5#��J��>�6��1��,�O�3��G�����������L��AY�?�vU}�s�� ����t�Wh��Z�o[B
������\{����B�m���1=^1P�.x���DX`��o�o���oo�m���r�:P���NN���=4�F�[�YN���6����&�]��Ww1�������0{��W)��g��U &%��� to����K��G>��;\��S�P�$��&�ir�g�zn��r}�E��,�K������S^���&��S���!��'��?��������`0���8j�1�%�N#�;��K�7���G�$U���a�X�t�^�l��#��i�� ��dL1�1�p2p���b�5�������$�h}J�!1����q$��e!�.�Y����/\���^�$ ��SX���;���cz�_��;�Gw��t�L���q/e���'~�l�{��z�P-U��Y�1����x;��7�
��?q��@}�N��.^����6������qp�<�WS'p�2�^29��������#����W��>�g���:�;_�>p6�Y�~&v�����7d��F%_���/U[��h�]��|�����n����7o����,��;`!�te#r��]�3����������g����~+?���=�����P���p��:
/��u"rA���|���.�����p����%)*<DR8�GT�lY��oV"n���� �E�}}{Q�:����=������V5�p�p�b�
�D�mF
��?�;9��A��o�u����t��!	�w4�����_I����O��'��3�*��FdI���s,�P��$�-�`����S���
$=qE�!Q��t4��X��Kp���Z����v6 ���
�(�;n|���p\�@��D;��CO���wy�z,�H��P��6�@�\?��d�h��X!��Y^�p���B�G�5]���	�1���`�/vo/�gj�3?���Y
<n����o�}-�d��h
��%)T�]T����\r\�O!b?��_��
�C.B`�0o���E�J��>:������j^���x{(�j^�����=�q4�l��~����������t����j�����XMZ:(� ���ILXB+�=[Y��}����<��*W�[���Q�Ph��R�����>�DrB�h�(mE����i5�	�����J��F�\��Uf���9��2�Mr�y�s@-:� w�T2g�]K'4G����&Z�
ND���I���)J,<�� ~�>X;��=x�����c�C����/ 6D�UX:�������?��<����q�;E�DV!�L'?��P�T���i
{� ������u�r@���ju�(��D�_qo�Piw
�������#���,`:^cAib���3��%5T'��a�?j��w%��W�m�v,���<,A�d�y��?_b�C�|�wb�t�QO/�v��D�3�����R,{g�r�0�OO+�ry��&��p6q�����p���5���Wl2 ��'B���������M���l`I�����|U���S#[*�V������Lfs����#�e��*��HL�QkE8��>Z�|r������%�Q����e�I�����m�FW<����u	N���8b��d_TP�c���\��)�J�J��1P�x�<��"�������������j�Kb}}����?�?�B���3��c=����*?R����N����6��<���������?�����kr�[X��"�I<�89�x8�*�gl*R����Y|���9b�J�#}���'����a��!H[��N���J}j�b�]:��?�U���k�E�&%y�.��+1�>����������*o��b?L-��l�.�5�����qy���������3����������C�L��P:t���+�R�u����
|R9wmk�Scw(x�?\M���$9[V3����I�����[�7�B�+�u��UG���p�v��(
�x�A������_�@LTb�����	�}�����G����?���rs����WW}�3~U�>C�2|S����:�+$G1_��a���P;	8�������}���7.��E�
.��p����z��jA)x\���[��v����[��BaX=�~�6�MR���
Ea����$���m�G������1��4$���C/��m��������N_�8���y���w?���2������kRE^�#9W�;ccg���n���i^�o~|�"��*(�I�%�����Dj/�#��db�::�/�_�":|�
�����{��wBJ�������;&�d�L�d?8���`Q�������|�������cn#��{���?w��B�,���*�S��RL�%w4:=�4N��B�6�EwtZ���.h!��*I�a������*�%�38�;*�+�Z���_Mpl������B9tr%G(�� ���@����[�,0��5��C2i�x����2�#�w���>y����4���/G�)��&����5������m;	m��Mj�n��rR�+z1�cP!����F������/�C�/�"L���E��a�I�=
��B�s.���|�����!�^��B``	��s�a��1�X���O���;����G�3�����^ZQ����G���2+�s;������������tiX���_L�������� OpfB�%��$i�qo�t�F�4}e{1K[��Lp�r��a��?��|���;��LBN��e"f��T?w��EI,����xr��=-
�)!�DC���H��������3�S����^$��q��{t���h��"���m������l�K�p��e1`,z���N��h)hG���y�\�;-�����.9���9<y�2��t�a7����!����L��x�	n����'������O'wuAK���=�tl��������J��	����Yc&�����R��P��vJXs��W��o��,hO��r��b���i�0�JC���U�?�Q(+���_�WN�5TX wY+��h�����s�KE�X������N&����uV���\����8�t���9�&���
��RL5N�O����j�6��>>f(��C����dn��D�x��>	:Zn���5\,�I1���5��;�����}���Xn'wx�S,'��j���D��$� *1��� N�
��4���Vy&���Q�-�i(2�m�|>�bS�X���/}����;�������b��!�H!^.�RyX*�UoT(Tk��i�T��v,�(���-�K�x�g�E�U$3|���.���`�*;�
��9��6��kg���"�bx�L�CA
���Z����-�o4��SsA7�'��v=�1l;�8�����`�6�?����@2r@�mE����'o�>$������'��

;����R�U�i���������B�G�r��92I�@av1�\Q��|�,��������z�-�I�kmb1��I�������9��l:�n������k:~���\��E�^@NE�t:.7���X�����^)��4P�D��`�^�=����v?�-]��?�Q@�1�UXO���3��l��M��j�O4X���L���n���,n{i�_�n~���U
��(=
(#2���-MS�R�5�on�7��+U��R(4�Ji\uGqW3vAK����|aO������_uT9�b��gY�y6��t�p��c��S�7��66�+��8���� Q��\(�
����"��01�
#44Erik Rijkers
er@xs4all.nl
In reply to: Andrew Dunstan (#43)
Re: SQL/JSON: JSON_TABLE

On 2021.03.26. 21:28 Andrew Dunstan <andrew@dunslane.net> wrote:
On 3/25/21 8:10 AM, David Steele wrote:

On 1/20/21 8:42 PM, Nikita Glukhov wrote:

Thank you for review.

Attached 45th version of the patches. "SQL/JSON functions" patch
corresponds to
v52 patch set posted in the separate thread.

Another rebase needed (http://cfbot.cputube.org/patch_32_2902.log),
marked Waiting on Author.

I can see that Álvaro suggested that the patch be split up so it can
be reviewed and committed in pieces. It looks like you've done that to
some extent, but I wonder if more can be done. In particular, it looks
like that first patch could be broken up -- at lot.

I've rebased this. Note that the large first patch is just the
accumulated patches from the 'SQL/JSON functions' thread, and should be
reviewed there. Only patches 2 thru 4 should be reviewed here. In fact
there are no changes at all in those patches from the previous set other
than a little patch fuzz. The only substantial changes are in patch 1,
which had bitrotted. However, I'm posting a new series to keep the
numbering in sync.

If the cfbot is happy I will set back to 'Needs review'

0001-SQL-JSON-functions-v46.patch
0002-JSON_TABLE-v46.patch
0003-JSON_TABLE-PLAN-DEFAULT-clause-v46.patch
0004-JSON_TABLE-PLAN-clause-v46.patch

Hi,

The four v46 patches apply fine, but on compile I get (debian/gcc):

make --quiet -j 4
make[3]: *** No rule to make target 'parse_jsontable.o', needed by 'objfiles.txt'. Stop.
make[3]: *** Waiting for unfinished jobs....
make[2]: *** [parser-recursive] Error 2
make[2]: *** Waiting for unfinished jobs....
make[1]: *** [all-backend-recurse] Error 2
make: *** [all-src-recurse] Error 2
common.mk:39: recipe for target 'parser-recursive' failed
Makefile:42: recipe for target 'all-backend-recurse' failed
GNUmakefile:11: recipe for target 'all-src-recurse' failed

Erik

#45Andrew Dunstan
andrew@dunslane.net
In reply to: Erik Rijkers (#44)
Re: SQL/JSON: JSON_TABLE

On 3/26/21 4:48 PM, Erik Rijkers wrote:

On 2021.03.26. 21:28 Andrew Dunstan <andrew@dunslane.net> wrote:
On 3/25/21 8:10 AM, David Steele wrote:

On 1/20/21 8:42 PM, Nikita Glukhov wrote:

Thank you for review.

Attached 45th version of the patches. "SQL/JSON functions" patch
corresponds to
v52 patch set posted in the separate thread.

Another rebase needed (http://cfbot.cputube.org/patch_32_2902.log),
marked Waiting on Author.

I can see that Álvaro suggested that the patch be split up so it can
be reviewed and committed in pieces. It looks like you've done that to
some extent, but I wonder if more can be done. In particular, it looks
like that first patch could be broken up -- at lot.

I've rebased this. Note that the large first patch is just the
accumulated patches from the 'SQL/JSON functions' thread, and should be
reviewed there. Only patches 2 thru 4 should be reviewed here. In fact
there are no changes at all in those patches from the previous set other
than a little patch fuzz. The only substantial changes are in patch 1,
which had bitrotted. However, I'm posting a new series to keep the
numbering in sync.

If the cfbot is happy I will set back to 'Needs review'
0001-SQL-JSON-functions-v46.patch
0002-JSON_TABLE-v46.patch
0003-JSON_TABLE-PLAN-DEFAULT-clause-v46.patch
0004-JSON_TABLE-PLAN-clause-v46.patch

Hi,

The four v46 patches apply fine, but on compile I get (debian/gcc):

make --quiet -j 4
make[3]: *** No rule to make target 'parse_jsontable.o', needed by 'objfiles.txt'. Stop.
make[3]: *** Waiting for unfinished jobs....
make[2]: *** [parser-recursive] Error 2
make[2]: *** Waiting for unfinished jobs....
make[1]: *** [all-backend-recurse] Error 2
make: *** [all-src-recurse] Error 2
common.mk:39: recipe for target 'parser-recursive' failed
Makefile:42: recipe for target 'all-backend-recurse' failed
GNUmakefile:11: recipe for target 'all-src-recurse' failed

Yeah, I messed up :-( Forgot to git-add some files.

will repost soon.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#46Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Andrew Dunstan (#45)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

Attached 47th version of the patches.

On 26.03.2021 23:58, Andrew Dunstan wrote:

On 3/26/21 4:48 PM, Erik Rijkers wrote:

Hi,

The four v46 patches apply fine, but on compile I get (debian/gcc):

make --quiet -j 4
make[3]: *** No rule to make target 'parse_jsontable.o', needed by 'objfiles.txt'. Stop.
make[3]: *** Waiting for unfinished jobs....
make[2]: *** [parser-recursive] Error 2
make[2]: *** Waiting for unfinished jobs....
make[1]: *** [all-backend-recurse] Error 2
make: *** [all-src-recurse] Error 2
common.mk:39: recipe for target 'parser-recursive' failed
Makefile:42: recipe for target 'all-backend-recurse' failed
GNUmakefile:11: recipe for target 'all-src-recurse' failed

Yeah, I messed up :-( Forgot to git-add some files.

will repost soon.

I have added forgotten files and fixed the first patch.

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

Attachments:

0001-SQL-JSON-functions-v47.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v47.patch.gzDownload
0002-JSON_TABLE-v47.patch.gzapplication/gzip; name=0002-JSON_TABLE-v47.patch.gzDownload
0003-JSON_TABLE-PLAN-DEFAULT-clause-v47.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v47.patch.gzDownload
0004-JSON_TABLE-PLAN-clause-v47.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v47.patch.gzDownload
#47Erik Rijkers
er@xs4all.nl
In reply to: Nikita Glukhov (#46)
Re: SQL/JSON: JSON_TABLE

On 2021.03.27. 02:12 Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:

Attached 47th version of the patches.

[..]

I have added forgotten files and fixed the first patch.

[0001-SQL-JSON-functions-v47.patch]
[0002-JSON_TABLE-v47.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v47.patch]
[0004-JSON_TABLE-PLAN-clause-v47.patch]

Hi,

Apply, build all fine. It also works quite well, and according to specification, as far as I can tell.

But today I ran into:

ERROR: function ExecEvalJson not in llvmjit_types.c

I think that it is caused by:

set enable_bitmapscan = off;

(I installed llvm a few days ago. llvm-3.9-dev on this debian stretch).

This is the test sql I concocted, which runs fine with enable_bitmapscan on (the default):

select jt1.*
from myjsonfile100k as t(js, id)
, json_table(
t.js
, '$' columns (
"lastname" text path '$. "lastname" '
, "firstname" text path '$. "firstname" '
, "date" text path '$. "date" '
, "city" text path '$. "city" '
, "country" text path '$. "country" '
, "name 0(1)" text path '$. "array"[0] '
, "name 4(5)" text path '$. "array"[4] '
, "names" text[] path '$. "array" '
, "randfloat" float path '$. "random float" '
)
) as jt1
where js @> ('[ { "city": "Santiago de Cuba" } ]')
and js[0]->>'firstname' = 'Gilda'
;
ERROR: function ExecEvalJson not in llvmjit_types.c

That statement only errors out if the table is large enough. I have no time now to make a sample table but if no-one understands the problem off-hand, I'll try to construct such a table later this week (the one I'm using is large, 1.5 GB).

Erik Rijkers

#48Nikita Glukhov
n.gluhov@postgrespro.ru
In reply to: Erik Rijkers (#47)
Re: SQL/JSON: JSON_TABLE

On 30.03.2021 19:56, Erik Rijkers wrote:

On 2021.03.27. 02:12 Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:

Attached 47th version of the patches.

Hi,

Apply, build all fine. It also works quite well, and according to specification, as far as I can tell.

But today I ran into:

ERROR: function ExecEvalJson not in llvmjit_types.c

I think that it is caused by:

set enable_bitmapscan = off;

(I installed llvm a few days ago. llvm-3.9-dev on this debian stretch).

This is the test sql I concocted, which runs fine with enable_bitmapscan on (the default):

select jt1.*
from myjsonfile100k as t(js, id)
, json_table(
t.js
, '$' columns (
"lastname" text path '$. "lastname" '
, "firstname" text path '$. "firstname" '
, "date" text path '$. "date" '
, "city" text path '$. "city" '
, "country" text path '$. "country" '
, "name 0(1)" text path '$. "array"[0] '
, "name 4(5)" text path '$. "array"[4] '
, "names" text[] path '$. "array" '
, "randfloat" float path '$. "random float" '
)
) as jt1
where js @> ('[ { "city": "Santiago de Cuba" } ]')
and js[0]->>'firstname' = 'Gilda'
;
ERROR: function ExecEvalJson not in llvmjit_types.c

That statement only errors out if the table is large enough. I have no time now to make a sample table but if no-one understands the problem off-hand, I'll try to construct such a table later this week (the one I'm using is large, 1.5 GB).

Thank you for testing.

I think you can try to add 3 missing functions references to the end of
src/backend/jit/llvm/llvmjit_types.c:

 void       *referenced_functions[] =
{
     ...
     ExecEvalXmlExpr,
+    ExecEvalJsonConstructor,
+    ExecEvalIsJsonPredicate,
+    ExecEvalJson,
     MakeExpandedObjectReadOnlyInternal,
     ...
};

If this fixes problem, I will add this to the new version of the patches.

--
Nikita Glukhov
Postgres Professional:http://www.postgrespro.co <http://www.postgrespro.com&gt;The Russian Postgres Company

#49Erik Rijkers
er@xs4all.nl
In reply to: Nikita Glukhov (#48)
Re: SQL/JSON: JSON_TABLE

On 2021.03.30. 22:25 Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:

On 30.03.2021 19:56, Erik Rijkers wrote:

On 2021.03.27. 02:12 Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:

Attached 47th version of the patches.

Hi,

Apply, build all fine. It also works quite well, and according to specification, as far as I can tell.

But today I ran into:

ERROR: function ExecEvalJson not in llvmjit_types.c

I think that it is caused by:

set enable_bitmapscan = off;

(I installed llvm a few days ago. llvm-3.9-dev on this debian stretch).

This is the test sql I concocted, which runs fine with enable_bitmapscan on (the default):

select jt1.*
from myjsonfile100k as t(js, id)
, json_table(
t.js
, '$' columns (
"lastname" text path '$. "lastname" '
, "firstname" text path '$. "firstname" '
, "date" text path '$. "date" '
, "city" text path '$. "city" '
, "country" text path '$. "country" '
, "name 0(1)" text path '$. "array"[0] '
, "name 4(5)" text path '$. "array"[4] '
, "names" text[] path '$. "array" '
, "randfloat" float path '$. "random float" '
)
) as jt1
where js @> ('[ { "city": "Santiago de Cuba" } ]')
and js[0]->>'firstname' = 'Gilda'
;
ERROR: function ExecEvalJson not in llvmjit_types.c

That statement only errors out if the table is large enough. I have no time now to make a sample table but if no-one understands the problem off-hand, I'll try to construct such a table later this week (the one I'm using is large, 1.5 GB).

Thank you for testing.

I think you can try to add 3 missing functions references to the end of
src/backend/jit/llvm/llvmjit_types.c:

 void       *referenced_functions[] =
{
     ...
     ExecEvalXmlExpr,
+    ExecEvalJsonConstructor,
+    ExecEvalIsJsonPredicate,
+    ExecEvalJson,
     MakeExpandedObjectReadOnlyInternal,
     ...
};

If this fixes problem, I will add this to the new version of the patches.

It does almost fix it, but in the above is a typo:
+  ExecEvalIsJsonPredicate     should to be changed to:
+  ExecEvalJsonIsPredicate.

With that change the problem vanishes.

Thanks!

Erik Rijkers

Show quoted text

--
Nikita Glukhov
Postgres Professional:http://www.postgrespro.co <http://www.postgrespro.com&gt;The Russian Postgres Company

#50Erik Rijkers
er@xs4all.nl
In reply to: Nikita Glukhov (#46)
Re: SQL/JSON: JSON_TABLE

On 2021.03.27. 02:12 Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:
Attached 47th version of the patches.

We're past feature freeze for 14 and alas, JSON_TABLE has not made it.

I have tested quite a bit with it and because I didn't find any trouble with functionality or speed, I wanted to at least mention that here once.

I looked at v47, these files

[0001-SQL-JSON-functions-v47.patch]
[0002-JSON_TABLE-v47.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v47.patch]
[0004-JSON_TABLE-PLAN-clause-v47.patch]
[manual_addition_fixed.patch] # for this see [1], [2]

(v47 doesn't apply anymore, as cfbot shows, but instances can still be built on top of 6131ffc43ff from 30 march 2021)

I hope it will fare better next round, version 15.

Thanks,

Erik Rijkers

[1]: /messages/by-id/69eefc5a-cabc-8dd3-c689-93da038c0d6a@postgrespro.ru
[2]: /messages/by-id/19181987.22943.1617141503618@webmailclassic.xs4all.nl

Show quoted text

--
Nikita Glukhov
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#51Andrew Dunstan
andrew@dunslane.net
In reply to: Erik Rijkers (#50)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 4/12/21 11:34 AM, Erik Rijkers wrote:

On 2021.03.27. 02:12 Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:
Attached 47th version of the patches.

We're past feature freeze for 14 and alas, JSON_TABLE has not made it.

I have tested quite a bit with it and because I didn't find any trouble with functionality or speed, I wanted to at least mention that here once.

I looked at v47, these files

[0001-SQL-JSON-functions-v47.patch]
[0002-JSON_TABLE-v47.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v47.patch]
[0004-JSON_TABLE-PLAN-clause-v47.patch]
[manual_addition_fixed.patch] # for this see [1], [2]

(v47 doesn't apply anymore, as cfbot shows, but instances can still be built on top of 6131ffc43ff from 30 march 2021)

I hope it will fare better next round, version 15.

Me too. Here's a set that should remove the bitrot.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-v48.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v48.patch.gzDownload
�=��`0001-SQL-JSON-functions-v48.patch�=ks�����+0����-��U��N��9��v������l���T������z�I�s�s�v����O��\t��=�?��z��A�����qwh����/z���^�;3��NgD�g�N�[{
hF���q����0�;�t��
�.�D��q�	��������K��.��F��Qw�5;�N�v>�!�h�~}sr���m~g�o_��s����=+r|/����)���\>EXKn��(�[������n�a;���s.���9?���#����L���{��?�K�Sk6�5f�V;������y'�U?�����_���f�p�
(��
�n�'��F,n���@c���ovz�@�"x/�V�!��Y�G�1�n�g��a��W����,hYy���{�����`f�����4�&�N�v��S�..Evjb�A�\��E��-�oa�X���,?���[��C-���Q1i�������V�d[����i�A���U��9@9S�/�g<��Q�iq�5���v 
���9Q�x���
�����O�
���7������.wz�D��dV	�S:	��,mj�("\�(������O����Y8dk��v��4��%������ep��]�Y4��I4D_W�|{�+�Kv\���^��d /�:Ono���"�'�,D����a�0����������T�2�����������S'��Ws�D,j�)���U_���'pX�
�t�
�?�
8�,��O����~<��Y��m�g��_�gW��
f�B��y�d�n�V$%�4\~�.�;�V���B8��3�d��rt&�AL��A1��`TS�~�gZ6)� 2��S���N�Z,A�1��)��p�i8r6��������+8:��UI�U���(��<?���h�-�;�hv P�%[373_o%� k��������p��0��Z�D�%�<�B�no9�X$�u��Xa*33����p.������2��-���A��/�,Rv�vS550���p/C�Z���s��+����b�$`*���M�~������L�;��+������!
�����
�N�u�;��qE��k�]	�"�����{)���i�>$��p�����1��H�)x7P���`��l>����E*��x3P�f;�	k6����vi�;.���x�����d<���^�5���D'Ef��k�$U3|�=k�
PD���cp�^x|�X��3x��D���c[�G�E����%���?�~�.0��"�o��7���[5��Gm��HL�k��{�M�E���v�}�6s����5a�&r��>b���p���rB�X��#p��cD��c=���;l���c���Gm���%��a��Z_��!���+��[,��Z��<�h�=�T�d�x��Y���D(	
�1�d�'�:6{��9x$�U��W�{v��q�e�@x�L�v{
!*,���VD�{#u���\Or�JH�	�����Is0
���H���oI)m,L)i���|-<V�k�0����5tk�D�%g����u���4�X-,BA��u,p#X��Yr���*�o8���SR5�q�������Rw�`��������
?���%_(7�����p`�VKXc���*� (�p������n�N~�B���a����g�s#.������7{���N-��d�}����<������gS��5�]q�H��5R4��@�x
����/������tz��������=oLR�
s�d�����X�.|����]�|/X8��� �z/-2ONz&�D����kA6)��N�{h�d9��Ll�!""����3�f���=j'_�\\�%�W�>���P�eCZ�����@c[��[������wm";�����p\�n�r��IM����� >��~X%���>��j��K#�!Z|!��SE?D�c�M	"�Oxh�![�stU��0$~��
Q`��s\�	�J��9)���(;3���K���������n���6����g�p�b�sX?.8�|�]��8�Fa�k��|��Kqn��������
n2T>�pxgWM�3��[����:%�	�2+���o����I���F�A���B�?�W���e�������0v��]$6�dOJ�ZOt���������`���?�+��Mi���������L�Tz7����L�E$�����Ki��i���
�����]�e��8$[��P�E8PVr�"M�DH47 r��`h.�=�l��oS�2
Qn8��
�d����Q����H�:���~#�q���yf��3}����$,���l�~���
��f����>T!Q�|q�2e�
y��ToD�o��?�
���G�#�Trs��*!�Z�w�B����x;n���,��������������/�����%���O^��}��d	z��?��/�"A������g��
YdY�N��N~�z�0�(��GE[������4l��������k�
�����B'���5A|��c'L)�q������[�}����^�\Hgg�>}��������wO�#�7�g�,��o�����G��������z����9���_�W�wvz���q�����(���w�x9u��%�
��=j�3�w�ym��I~������Z�C��=.�������
�&v�-H`S5Z_il�@��7c���j�+V�Fs(���tV�Z:��+	G�"Kj_L�+2�jg�*(F���9m�F�%��8�T�DHy����e�]�[{���u�aUL�Pq��o��j��hs1��4^D���#�:�u���66�LO	��*"�F�X��$���U  ���mb�T�
9i2D�Jf��H��>yDgRL�p��~0M!��*��/s�yPMY�:��Om������7��'b�xT�����s,�ap|#��
��+��9U�E���qe\�C�>��eXVl������s7j�
�z�T��%f)�%*�l�T�/�49].��r�Y�O�L*�R!�����=?�"oeF?�������W�'���LLx��/f��|������2w����%ke�;kv��~E��:��)S�E��n'�j�]|V�q/������uCyd�������n�vQ�k�0���PU�u�c�o�+/G�4
�j�(��aY&@Js����J���I��+��D�����&�s+G�J��<����b.��A��������7��xZ5{��D��(R��u���At-���O_@BK��[�:�����
V�G�W�\L|��~o��1���������������ns��g]�j��]��;������&����|�22!�m�����qM�LE�����
(dRa:m\������3v"���\�lZYr�+/��t]p*M��O+d��oY�^�������Wd��/L�%c%�V��%���?������*�����
7+�
o����&�4����P�T�8|�:K��1W
W�r$X(�?�B]���]����p0�����31�:�����#
����3�L�<��,0I���$c�#�����)W�[�- Xw!:�H!��&������aJ������&&����@TY��I�����������C����g����a�n���C���ML'i#��>b]"�l�����S�t�����y(����u��oC��QPj�D�������I�m�m-GV�a�e�0 ]�
G�V�6��M�NT(���|o��ci�)1op�����1B�/K����N^@$��m��0�1�BZU~O=�)�h�V��j����/���G����|s��`k�4^�'~��7����I�L����JL<�Q��|�� �HQ���#��\<r'+��f�D�u�b��lq����V�L�
#MJ6L-8Zc�b���r�L��:fq����EU�a}��ba�t'�E��:F�-H�����DR��07�wt�F�=���X��QFG6)
&�^��{*h���l\���P�q�\p�6����B�+��c��*9�������4e�
{�+�eK�T������E���t�c���r��� �"�X�B�KP����8t5�����`����Y�������j�wmY��q'��[�.H*�x�g��<�*OA����v�%]����������l�x�G5"�:�_��]�gj�m�l?6M�:����;��sg+)�����L�zR��u��z�qy���,�T������J���V�v��qU$��+u��0����?�Xh�k��=�<�vR���1�U��n��0��V+O�,�����|�^~�dm��u������'��ka�Ph"�?p�|�'SV�C	������(]���4�;�b)?�R}������f�)��M<W���k�+���[H�A����i$MI��@�$$\Z�7�e�y��{(��:�D��q��D5���qmU�LW�	wj��|t�6u�DD+���j��^���f	+U������������mc�[�g�~&�n����@n5������`���{�-Uk��� u�=,\��@���MIw�Z)��.�A����A�|OOm��
���������e���0�t��3(�������i����eq�|���;�V��6;��~G����J��F�����������ks���-�����^�<�����+�&%�%�u�G���h�}����G[l�.����vU����vrN+�>���'���]G���MRc����nI�[}}H
��=������������!!L���H�I�>�6��^}�1�������Sx�;���;�|���HZ)9���N����#o��E�
���N>�W!d���y�������7�|�������vl#�_j�C���X�v���`[�om��^�y��J��%}�$�m<�@6�k��>={�R-���v���L�������cSeD�IQ�\�;]���n��o-���&PB����A��P� ��2�~hp�~��v�-��v"=�&�73��r�-�^����4���W��~zh�m����M����}��=�a:�+c��K�s��F*c~��I��������=���#�f�o����������)ka�����fH�z=�����wo��_������N�%_�=9=K
TYJ#C�t��?R�es��1���I4x��k�����c&�X=�����r���l�y�c`��T6����;
n��#�!�l��#���v��	a���zZq�B��z���'`�>����<;Q�b�����+��9���'ecE!U��!hS�����s�?�mL��������-���['F����y�+L�+)�q�r�UK!�=�*!%7OI4�������h����#��]����gn�>�fZ���Ak��7{�������f������lFW

�@wV�A���f%F�32��%c���:
����eF���-��A����0���3$.PYD�:��3i�8��N�u���(�c�XU��
��`|����gX��4�{=8vop����}�6`-K�:&�
�:�~B��vq��[��&�1R5a����;�-4�'��UC�M����C��n�2���$["Q".?�Pp��V
��I�+�Rf������(VYK�������G�v�)�Vb-�j"��d���=Z�,��������2���Y)�eV�9K�Q��fv�z�;K�Jw�o�^
���?�R���^��������_b��#v���>��`A6�����Q����?�H��!���������G�K?
|
{�u�����G�9��*D��F�'������X���;O��b
�d�����S��v�3��1���<���;���>�������i������9���M��&F�����2)�
�a_�dE��a�����u�g�����{�w��/��t��<���O��<����&K��I�v�jhG���Z����p���� �V��d�����^r�T�<�����{���V����pA�;������%�=@��[�����w�����=��OI*�GM$�H#'�%����R��!�*��;5�s�7��BMU?�L�*�z�T��������s�[a�!����N�:=�L�\����I�j�'g�������x~e)M�zf�N�K�-�����'�U�\s��$�%���������R,.���S��2���k�m���x�� ��e����H��A�8_�'��������c-&2|��nf���K�_�&]^|$N����g���3���!��:�K_���<����+w/d#D��|2G=�"��q�K����R���wz��k��������a6������&V����|���CW&��Q����1z���kvg�zo���{��6ndQ���+��3iQ�H�������D�4"�������D�"6e[�����@�^(�������d��P(Tj�{�������Ns�����}}'�{q������8����aP�f=�v���6��
���k�H7q7����{���z��wM���5�dz�H,J�ZZ��>��u��s0�4�! �b�o�xr-�����m��d�=N��������A,�]G^�_�9v���U����u*����:+���Jk�3U��9���HvU��*
��]�y)�����7�����?:�|��xx���J��I���]��^P	M$����n8RGC���4t�Y�t��M{��L�W�6^h'�\���>��u���Z������A%��:(��~��������c_X�Y������V�U�&EIW���e:��(�2]��F��j�K.�}��l!
�
���E�!i��E�H7*����
l�E'��:�%��6%���h��T4��fS��+��	�Z� ���^X���e��������R6���,�H�����������5�b��H[G����#5g�I���6�F�2�K�����|������q��ji�Ba����@���	����!'
!����������#�I�6Q����4�p&�05�{��h��\��.ba��2D��i�t.��Z��T�$?h�jds��7��z��4~��x�=�f!V��.���+��A��(�2p�����^ar�Xz`��`������^8x�ta��w�K�{��QB���!Y����v��i�������������S��i�K����s����(���o�go�4��i9~�5������7��<).,�J�� �O��L�*a0��g� nIe>1u�q�XO��B
�����iF��GME��t��Q�.a�a��*�������N�:�����dmx	Rj��>��(N	�����S03G-�m��\���V*|}���[�f�,O�\���tx4J�B�k���9M�0��������Yo2�i�}0E��q�r��S�_*�ir;��fv�?>���F���`:x����r��..��9%���!zH��������f�����4�}�qoP�N������n"����tL�_�}�����S�w���}]����~N����J{5�"T9�v+����� ������{K��^��^�<;������?���������6|�9�����c�
S��>����yE��nM��Q�j����4�!"�F$2�v�[G���{���v��h=���
�%q�:)�1r��r���Y\�!0)N�Za����-2�f�qTV���U��|)���.Z0��2��^�hM�:�%����0��}�ul0�O�XmS����Z1�L����5�w��-��/M��hE��_(�t�<eO�g ,q�i��;����}u-�?���3#�����`[$�2=��K#����� Z.����j�6��/�N����8�R�I����B'>n��N�f����X�&h3��8��y��5(���/����G��FU��$~-�d�Tfv��M�AlR3q�������;d���������B�����eA`u5jS����6�"���(O>�zY������7����+��TI���a�h�������3�#�b��e�,�K�K���z�)R�~���p������(6Vb}I���R��{�[������G��o����w}w~�|����S�S&��D~}�y������L8��+�T�q�#�Q�~6j/�T�=�@e�D#��
���n�2]:�X�0��� �x�����\wT�_��.�L���o�~#|�6cW�����&�)����]�d�s���v����b���R���\W�O?�����W�{�@9�,�(��qVs�!7�,�dB��e� �o�:��;�!�������h�'ni����rj0�i���GK���4
}K������K�M�0"���a�����������
_���j
��T�����|z3�z�Q�FI�0��w@i����`m
W�pG��yi��!me����2��6�&)�����_���`��V{�LO8C��L���F���
���I��,?�G�	�0� U�/�A4��:kL�A]��I�%P(��o�}���ND��f2���
��t����)MY�e)q��o�������eP���!������U����S��?j@ho��P�T/��<S���%�Z����������^�Z]o���i�k:�`e����O_������������U9:���'J
��_8�,X����HUJ�HHDFG�Z|��F��p�����������>���6���4_k8��8O�����GbS�?���n K`�&F:yh����oFd�	��L>����G'�j���"mm���>,��>��NW���,��[�f9eWJ����I����G�����t�:�e�PN�[����>0����cQ��������N�?����6�r��}�y��;y�����9�4���q�>�?�?���3i��y�)���F�U#�W���U�����)
�����I%����B 7$�(2��8h� �5R���d���3�v�����8�9�Y~��[}�����N@����N��2���n��F��uo*����{�����.�}.�}�8K_2����m�?�1�5����]�Y�'J,��~E�X���T(�����z��k$����C���0J�R������h]��{�c8���1�����#������D�Tx�4����������'��1�a.������{��������Vjbn��p�M�F�g���//`iq�����P*����T22�����BY�4]�@8^�i�8]�L���i������H���T���|��y����8�F��0���@��4������e�:�0g.���a�C��d/��"����[���
z{l��!���"���/�������y����������z&^���������[KP�_]�oeT�����>��u����c(���y�Xw����s��"����|m�����_����[ ����y��_�Vyk���,��a�������b<���+f)���������������w	����	??���}I6��e��Cz8�B�c<z��?��6���/@��as���	+�:�%E���Z����g�:���Kq�xc=�[���u���A!���z��������|���s >�s��6/>���;M��j�m3��Z�vz3_.��`j52��sb0�K����0"l��O�Ut�}k�F]�*hg@_�u�om"`*����x������U7:U�Um/���(b`��<9*�����V2���n�%��~�*0����)���������T�z��HAI?���=��4���o��U���`�f�*td�|��6��z�p!��)
u"-�tzM]��I���o0�1�{�^�>
.��d����*�I$�S��j�����`i���.	D�*2-%]rB(eWr7�zo9�������#�G9_^�SZ�����wf��_dT��C��9n�����o�mg1��}{G��LfO��U�����N����-����;�H������A�����f!��1�7S~�4�~<��F���L��#X����
�v�>������D���5;):��N�;��N����RIo>J�u����\�B����Q�c9��q��A�~��A|�����	�$�H����*�sO�W�r-���z������]��=� �`��+}i_(�g�K�"���k�\Wa$T�@l��
����KO57(�4�f*�i�����IK
}�1���U_vcI�0�C��1������V����cq���x�������������?�@A8����N����kyv��V�I����%��S����c����`7|��� �5�	D��S}�(YCl3�^���s	��~��
# �����{)t�t�0@%��R�z<hl��+2R�y����3�3�,s..������;����c�@�L��X�FuR�3o�H?��B��M�C�T���T���1�<-���e�J�����g��j�~JUr�RVJ������&�bu~g��������W���V���*5/��~���������[�;�H�_���bN������h����D� ](��k�<C���Z"�C�'����?SQ����
���~C��h�`R�������Q�w�����$������i�T)�'�A9E��w2��#K���e_���D�Y��S%_=�����g�|��$��������c�[+���2���gI����b���n���`��B��B���m9��4�'������G������ ������h]�h]:6�����q�&N��t��j
��h7X�"���Z�9�VC�Q<��6�2��:�:V()��U�'��P #��~�n!���^�7m3��C���ByRW��]Y{�v���a�9
�U����+��f�#I9�F���?����J�[)��yov�s��h�a<!w�����8��w7,I%K.+�Id�E�t�����L�Nr�[0-����B�X�
K�l���	�R�R����"&b%����B?Q��|�$&%8��N��E��y>T��KV����&�=4����I�a�N���xE��f�K������-aX`����N�����>�>o46z�u���]�i���Ge[��:<����������S��a+�D������P4�?��RT�w
�\~0�����6[�g�&}>1�S�K�L����L{?}q��%�~�P�jn��R�����Z�&{Y0]YP�T���x+^ny�7Zzf�+).<�|O�Q�D�r\�|F�]��c�+Vp6�?����Y��U�����!��?�Bj���<SL@�(A����|���;�8�����"<�
�D?��=
����(��;��;�e�95�b{9i�B���g34���Ba/�2}B|����?+���d�5y�����>���e}.�`QE�����M�����n�����d"����d;����l�D��|�����~[��|$��S��^	�I�=l5�"�v@t����q�XD/���.	�O���d�)e�%Rfz�i�� jo��PM��?=`�W�u�������w�Z��Z��mG+��fc�V�oE�1K#�B�zY�,�T&�I\��
���(r �_Ox�9�>��%��M?�����e���c{���x����4](��ffH96"���y�(�{]�xf��R�5�N�m�q�x_�&���F���h�v��w�|"t����������E@ �t�{��� 7�aEt~������2(�����/Khx~0��n�b������)[���#��+�E�5zf��A�"C�h��������-yQ����������$@�ZV�Pg�u���W�d�� l�O�{�n�����������?���c�1"�l@��g:���Q��x��d,@)�cs=B="i�P�s�/�e(qH��*
s3�*3F�������h�/�0_�`SbP�����  %LFjQ_1S@W<���	NP��.M����"�����9��?�^������}�"u/l�I�"�����kw�X`���^@��'���I2S�]\���pRO�_����6�R��I<����(��wR�����zccwwmm���l��n��F�����������������cAM��v���V��T��N�������D�m?����uLF��2�����W������l���&�=k[I���
'�bg�����{z�z���~�O�2�]G�C�7���'��xp3���K���lm��UP��jgg�7������
z��{[[����VE-������D�������A�F���fG�7��8yBZ���tI�f4��&I�p�0�
JV�������
�4Nn�AopKA��8��-���nms�/������t4��
2/������<P���j���<��q-R��@�=��A���"�3Cr����g@@�pG��+�ak2����m����d:T=��{�
n��zG��(��&�����������c�����h8���=��j�a������z�=���d0������o����`��cr_����>�PU�R�.n�8�l/�S�����D�3:�*0���o�^��WL����a�F`�xL	���.ND
���>>V���s*^E�TU	 �x�s���� V����1�L�2M�]����2k�u$U��b��^��f��������9��}���SM@m9�c�-�	K�i�����Z��G��8��i�sFc�,��^��Y<�r��x*�E�LO�LW/G���S�9���O�i�X�_k���M*IT<�I.+f�w�=�{�[�Ou���I��g�Vy�X��#9���j�KkH�0�b�="����t�5�
<��j;�JB$mpF�O�������j��^U����W[z�����B[z5K���j��^
niox���j����n��/�~�U��[��~�e��*�6�����~�w���9��
�C����3�Ox��m��o�^k���N��c?*��5q��8n���
6��������Wf���l���V`�����z+��	��@!/*8EW"jK����j�e�0Fp�!k��A|6
!eY����%�8�����,:/������v;�(����V,~){Q�gZ3�x������6���������A�� )�?�{���wh]M
5)���(9�����7��S=~���=�j����G�^R����K���-����i���9��*����p�rD�C,xw����E�^%��g��f�y�?L�Y^5���m���A����	��A���w>�#�
=����YQ�+W;���R���u8�q�z�8R���s�!*�j��x�
Q'��x�q<��_V�Q����L�������(�<\���V�^1�x�`��
���w�\���A����:����v3z�(zHuH�]�~��P�������:��$"��6�<�?���0�#:����xD�A�����H����q�s�&���=\��a��&M�AJ��F�eu4��tPI�4=� ����f"���1�TJ��g����o�d4\�%���,���2qopY+|����^dM���=�7�1E�'hP����;���g��b�7U$����J��j�V���T>�N�����d�)�4�1��o&C��KK�"�M�s�<1�r�c���W�c%,yV���P36{H�"	{"���u���E����r&����`eE|6�VK�YJ$f���`0��|��s��J���%�A
��^#��QA���f~�qq���>��'5�%�f���b�K�����q�&���[XU ���0��_�����J`����h����UE_��������/P�
�c*��G������n$F�<B��*z�W�m,�]0[A{���������~�yY��������!����!�#LB#�`���e����k�?�r`mjK2�>�S[��j�y��j��VR��kb�;�?�@��	��TG�J1��LI�����@�4\4@:�"����VI�3��p���>�`�ar���pV
%���
��Q�k�f^���TP�����S�� ����,
�����p���DMWz5�]�Yx�Z-�K��li����V��g�wF�&^�[l��[���N��N�������.1_��]v�J��a%�v%�2j:�]�-[o������u�^Y`zBi��� �W����0X�����l��=���G�;����&���s�����F��������eG�j������
���^rP�d!��Q�;�V=�������L�0������,�o�j2���s�����p�di��8�%>E!l�ZkP}�*#��_]��#�������|�,P���-���P��e�M5K�R����9�R�q���Y�_9az6����$Ex���8�kp��*
�{v��@!��z��v
R��~�>���O=���� �XS�LoXYXA%	RJ���T�W?
���}���j-������\��2�������'��T�
��T[wJ
��d��ec���1]�U2*� �Bf��%���h��c"����<~��Y��Z|=30����3Y�J@	���pO�G���D^+G����/�3�&�i�WG�<����F���5�s�s�YW������T�����<�^]O��]&���J-��Y���x���0�T2{�T��f|1S1�U���B�<�E�/!������m�;
A���O�&2O/*��-�Lf��\L N	
:xn>��
�����!P��]�u* jy{\���.�����6w}o3n4�{����������n}o�\�^	]S.�vj�F��>6����5�� K\Y��$yr���S%Bz��\a��%{���<���^����V�bL	��B�$Ot��<m��Q����_�{�
�"�����j�z���o^�$O�����������m���'��^��i��:��-��nX�t6��5.����lx�F���i�}_��`�
��'�g6�]���.6�?]��9��E��6��3W;���Q�YP�D�&DKp�j=zt��nvQ������i��U������_�c�����pY������c����A��������I����U��t��Ms}�VT����O�t��5�����j���og�^�����Zc�^a�J�O!����Dq�&J�&q131�EO�b��p��_\��0C��vnTe}�M�k����95���f�B������Jp��c va�����z&��1J������&��vh
���F���PDD���A�������^]#*4���8S�1�c5g��g��Z�q2G��L[hh��M�^�>w5�_�.������h�F($e�dp���Uu�)H��uS�NS����W�{��H�K��J�����U�Wm����QG-�I�0���H>$Q���`IQ^�p0jP���d� �����wm{����fw��-��3��`��^
>&G`��i5����J��|��;|X#A�H, �U9��|��>k�b��u�����!�e�D�k��G��E����������p����/�g��63�^����@4)?2M�#�)Go�
0�L�m��G��$:	�AQ*�h:�"e"[����9��z����.E3����8�!�=�
Cz�H#*{<����xsT%�"Nr�1#c�!���9�M���^�Mv?���i���N��r��]�w�Tro�+�?/�g''8�����_�Ap�
2�RhM�D�.�U-�E�����<��px3�&��0"��U�8D�eO�I�!�����������~��f�67���
��o�����
}+��t�M�a{q{�W�V��4�aMpk�5��^�W��-��mD���2,��`������}���!����>�%�V|��M�f��Oz:�s
n�S����������d!e�a}�@�|�-D���+c;�*������ @�(`w?Ng���vq�@�j%h2���2*ZC���)�]���De�}�y��(�����!���&�X��#�N�`��������v^�4�K������%��4���?��"$(^]���|�#�=���h:^�L�_n��2�UX��[+3j��J\�!i�FcJ�!2���KquU=�Z�X�-I+A������_����XJ�������@�]h��a�>��
��1[M1����&�/��>��a��s{ar�\\J������G|tK�����X��VO���_�>��IOV�	a�u������*z6Y'z��7!(�b�6�����p��?]f@3�����}���:XI�E���Zjg4_�v�J.�]�H�0�&�|�{7:��T�5gf�R�(��	�y�
[��t�a��/�8���2^7�s������'?S�buY�=�]���a����#n�Pe�c��2�%��#�d����q��h�9�����N��6���)��Y�8��[�v�WI��
n�P��b"�u��0
��k��@*��cs�|-�k�F�R�R:���������]F����������o#V=sX'��]�
q����g��L��dX��_7��J�Al��|���8�H���
��C����@w��q�AY��*�!��u��`6���])k3HB��S�����z3��X� �����61��#��n��S����S7hw5<�`�2�~=����I g�K�1��Vr9�d4,QI�����
�S���?`f�����I
�W��p+�-��D`�	�Y���U����@�+������$�0d'L,x&�T4�<�S����1���n��PG�H�e%�(r���
�*D;0
�h�w���1�|�?��	�7����|�W'!q����rP���f�}�?��c����)�~���>����Z��Z��,�>���P���W{y2���S�Zde���g���R��<�>;#��^�f%�
�H-�:�&�q`�^�=v�DGRF����������Z@���?k�2���mo���RI/��������W�q�}r
����v��J�rw����a��S1��Y���,Kt��^(���/��Lgj^O'��%Q��!N������r���i�6Hn ��qPr�Ij��PW[#`\�h�J�;�6W~|-��`�s�6o����D��7��aRV�W������1���7���V�V���J��Sn�5�&U5h�g��W�7��!�[���v������u(2���ii��:P[D���b����'�G3<����d���+�}��1EbUFQp8��,�\��w���3h��u�<�T�mL���*��������pl@�Q��A�% �����q�/E�c����>���g�A0��7�f�m���9]����`e�����T����L��i�S��}��kBw���SIl���p��T���"���Pi���:��%��A�6��G�F���m���}Z�%4�+n���������HO�W��:���CW
z�8���r��WK��k�;�����
�P�T>���yD�:�=;qAv=M��)~GT
m�<��0b���Q�\e��b2�X����� *�a VWcpx�������S�R�}��k��WD"h����=DS#4T���h��pn���x���R����f6�O�����Up��-����.L���=�\��hi�V�)xC��1��(��G����f� ��
:���\�(�<89lv!��6:h�vZ������������XSDi��Su���&`��p��f~�Q%����@���|�����b4�Q��t,+:$��G�t�O�4�&����06��o��$�H��iO �3U5��u���%��nXt�8���h�Y�6;j&��dU����+�T's3@=�M)3���������8�e5�����wb�M��!$?V�
�R;�v�C���Cl��D�'�A��a��9��[�!O���&�����W|���Yx5��1xw�O� ,����d�h;�W'
�p����u� .���!y��70qJgqr) �	
�k���{�
k�<>4�<X��B2��8��x�E��]�'�HnM�)mGi��&E���GZ��l`+�T����R
���	�AB:"r�������Z@�h%
�U���1+�z�/d7���vE7���\�����;(9+B����8�Nu�>��0���7E
�7+=��2�^%��+��o<�,	�8�g��c�'�G�����*u$�!�#W@	�,@��*e�+���u�jDUdM�,�s�����#<�J�sZq�$/��\8�oB�e�.���^����u���]4=���
����?��`Y��4��,`qG�������X�}�~N
���(��-���RWi������uH9��%���e����q�Q��y+l�B��7u�e����%��������g�D�''�qCT\Lq��[�%s���6������m4����dI��Q2_3�4��F!�:���f<��O?��9�v��n���W���P��x��f��ku���q||���h�'O8�����f�������L@q��3W?o���lMT�Q+��TR}�i����7���a��F�\T�=�xo�i���]�r��=?X��w���G$����9���	3���s�>H���.�������S�yE����
Moe�ro��S���Hy�7��<���:��*������eN�������������f-%y��Ox���fK������5bj�kR8Y��H��DO}�2/���>�*!vD�A���G2��	W���*���$�&<����a��	^!���O�'.y4t�P%E'�dH������W43���R.���1�
��`<5���me�)3c�2� ��Q0e
%hw���W�l�M:�����L����[v�CF�7����Q���-cZ;�
�J�,0�Uv��y�u�������G�
PbW�=��a�i"����9�C�VcMg
�U�'���u�a���ah+�a����C7��V��`C�[|��~�?�w}��j�>�
���#
�3
�B
QZ��*�j����'m���j�����
 ~:7:,4%_=�9��RS���f2���1���a�}�nOn�i��J���W1�Q��jDZO=�^�Fr�K�U$��	&��g���C�f�'��,��n7��yA��.+���%���G/�����y�������#m�B���0���+eG�GO��5PN�4���n����wda�)v����^c��]�+$6�1}d�k��>|@9����h	��J ��Bv��Q���=W��4r���Io��Gd���tk�����q��N�'�����[�=I�$�;	W����	�3�6E'4Sh����A� �sy����IW����\���D�9;8�����x��
����
�Q����6�w��������`��1������`Y����e���P��J}66�ju������*�P;:��5��|1��a���SuH�<�VR�JT�����|Q{D�`�� �O�����4�1.g8;/�5��1Y>t��5�F�H����w,;�V��]�U��}
N�Y�_v�3���v�"�i���$�dn1��6�^�R�0s��y[�o�vv��w6���6v7�w6�����m�n'���uh+��i+���L���J'��������RJ�a�����Xr��)l=��1F�� �� w�:	���������:���#����H�o��|����Z�����a��
��`
�����`�����%�Y�^�(8��fb��7
a�+ a�
`��<DIHL
	�c�����56��Ji`������a�`����[�	
S%:u��s
T&Xv���B�a��2,������Fe�V���;����xF�Z3�.����	�
nid�R�t�x�P����pJ�;����Roy�J�g����Iz���3c���J:�_`t_���$w�q���+�������H|��K������z�Z���E�2��}|��T)��$�H�6U��v�T�?���@���j�l�0z�{���e���w���E��;������2��U������h<������4�X�{>�����0\0[=Ma4�b2��b���������-2\���L�>���:>��1If��`Tp(�i�IR~��E��j���+��0���S���W���}�B�`��M�K��t����^�������<�����jiH�5|��[�0]+�~��bP�R�XV���hf�S�����p�z�b.����;���5s��"��-�T&D��B��J2�+Xy�Y��q3��$o�@;�T�8�o1P�{K�������AJ|�^J���2���Bq��cs�]e4�(L���a%�y�4��bjN����?�4�N�H��H��t�H�1�e���/:K"��QCD��E��_���q&]h��� Lhu��a��R�l��Zf]�Mwu�Ei/$����9'Y.�J��?���[P��Pd�O��7�,��z���$,������$<~�����i�������B���@j
��_W���~��Of�\���:���w��#���:�����f�.�6�l-R`�Q<�;���o������D*��z��^����l �*`��?@i e�3z�8z��� �:].������e�0����������([�[��c��S������1r����:�{�J�j^0�`���gk�.�j�u��:)������F�aV;�F��)s������+j��Ge�%.�
��:��9�JEMj�zVkF_��w�����S�lJ���pZ�^�����j�S'��z)���)l
���vH�X8IOG�9M_aW�a_���zJ-S��P�XQC�q�jKrlE�i�9�`i����FJ5@�z�^C����e5cx�����1{��8.����c�@��Ka5s�i9�d�i��Cq#g�#dd"8��EfT��7�q�����T�xg{���1���������n�!��P�%�S	X��%�Gc9�.�)eI��E�����"W
2�b���[�#q����L�a��������g�9'P��GQ�R�)�� c�1��'g6��?�,�d`:��)\�2n*1�{%g�y�<<���yz��h,4�B;#gB� gF�q��4r���-2�,���Njgb����/������N���N���;Hc���+xG��XR�/�s�p���9XdMmREk��[�`�g��s�l�L���?����s����+�*�<{�`
i����C�u(i������y,���!:s�x�����M�����yz%�Do1�]�2D�n�U���{��y�����(�.>��
0=_*��3{i_� !+���T(qmd%��Sc�/�(�.�{�;B@k����A>�r���"2^�q��<�1��'w*��\A�g�%�]s3{Ga*lSf_�X�*�d2kI;���v�
r�\\?g��I�po�C������6�IZ93�h���d��b2j��@y�uL.0rlcRT��5��,@�� ��%���xI�F/i���<l�,3�+�Ri�]!��3��:ct{~s~N���%=A��Fco��[����('qU��I�n��/o*�g:���(	7���Z�/~=�+/����'����2/(����o(C������(3T\Em\-f������
�dE�e]������r�Yf�+��9Q��;�"�n��w������z�Q�X_|���f�f��w��P���n��*�"�a�h�������R�q��5�Z)l+x���,
�Yp���_(�r�Ev�|[��<p%@��1]�>��H4O)�J��$X7�]M�r��\������q��6�m�l��^���l'�bR�jP�Z���(B� �?��`|�f��HqO��5�
_�\��~c�R��R������h�<�@���T8NnL����x�Z��mD+���Z}}���Copssuk[9�M.����G��D��)$���iJ	c�H����"Ht����+�x�j�b�O��R��((�����t����a���V�FD���V(kb�oP#}�J)�D��r��<7������$eB�*��3~�;��[�U�� `u��w����gg�+�P�������*TB����Y|Ewx��Ca`Ue���<8|�}����E&Q
!�����h�gd�&a��b:�Z�o�1���I�?]�B��&cy����3Z��-�}�
���F��00�N>��y���u1h30����#g��W(�����\0��{�����zRJOE��w��2@������������gE������o����zy�A@
�M��m���:�*ar�u��<��u���uN;���K�k�j��<yD�,cM��g�M��{�_�p�!������q�
F:(�q0Y}���X�D2�����
t�4��& �(p�C�F�0HUr�F0��DeY��f�.����n��"T����EQ�?�����I�n`w���\*���/./:��u)��,��D��u�1v�����^\��[�[�A�&����d���*�h /��ue1���#��{����x��Dl.���o`T������]}~}�j�L��S��F�4j�C:lU����;��q��(��i��:���
�X=�C���x�:�PYDg��899:i��i�v�����
��������]e���hR�vz�v�[E6FC��c���q|q��Y���(�k���n�3������CW�ax2���x���<�ta ���g���a�),�z����]Re�
%t�W�a�r��-D�@3)
��R����A���I{[��I{����I��ea�75��l#_�.��oTY������9�s6d��9!���B�_�)����M��[0�Stl�(y�	?�G�14��j��HU@��v���������h/2���_��������cs��R,�f��W5�%��*r��S�[����m������#�^�F��z��v5�Q���@f���� :�?������c2 ��T���kk�B��A�U�����a�>gK��@B^%�G	�0Ut3e�SjJ�6��J"��s
~J�K���:eO��_K�Bbo��I���OP�E��]z��������K��[-cY�L�R��_&�+3��N�i$n��M$n;���j�d��V�;H���4��t ��@5AC��,����Q�����E��;�|�[�EJ��t��h��s�>�����a���Q�.�Y�g���/��=��!��8>�_MU#����5G��Ej�L2%=|'c���������j��i�7���`����h���w7j�7������8di���g������s�SF��|������x�8}�(��%��]PmV����.XJ�Cr�-5�XF����B�z'zq�*s��|��4���q�����wzQ2
w�R�r^��*��WC�j�3�p���.�f9�z&Z�����d���k�[�
E>*��$7�nQc��u��<�f1��ulwC����������fG�rw���v��m�d�_���S�z��l��z��fs��"�+�>��K�mx�6���}6��{�����!�k���`5�eo���e����=4�%�0������@!��1������lo����[�	�-W7��xy�oF��;��Y|�T<nOg�W�����R����N��f�K]��lmk,��F�6!�hR���h~y�O��Hk"�	dE���V������z}�Y��`��,�rj����N"��;s����^�a�����~�mU����+f���W_���w���>���]�MWM'� 0xz�j����\	.k����8_F.�,#d}�4��z/@_�i��3g���bx�f��p}%��L8"�MP���`�|#�b��fn�4�����]`�J2����|�"[C����g�/4\�uY�!d�W�w����H�r	4�����fk|�L�K��N��E�����,����3��
B����,���(	a��R����� 2���.C����RS>,3�#n�m=$G����]�����xPF
j��Q>�,����������~y�$��dx�P�I�����	Sbb��P��5!����X�	-z�b���\�	��_&q,%)�o���!iq�f�1��5�H�!�1�L�-��$����������[(Kj��X��C����������:z���
ap;���,��n�Ugs`�.�7���uN^7B�4��B#[��vcM��R�\�r�Y��/��g���;�{�H�,��/���R������c��G�pT�����������9��bV�����z^�a��z���	�?��.R��V�W:�;�$�(���t��`\�E�o���������m:����l�0g��;��wOs
�1��z��$���������Q�����*�N�C����?�9�o0���i��/�4o�����Xx��������������s�F��z_6���M+����1&�]�W����M����x�c#�T���@��Vm���:��[��������Xv���@~�����#��^E���-�E��:���kH�gX��7�o����������3���6&�/|��37����M����H#�a�����{U���Wh��F�����s�`�����s\�xI*����:��Nc�|{�����6�5;���n���h&�ERTA���
�m�����:^��6*�Z��i�vV�}�����g���m0>����(r�����9V�O{����������Vt�y{��,�}yr�z���� T�y���HP^�ut��T]Z/'d�~��NOF�tgjleOV�6����ysv�:~�N9;��NZ����T�:��b�g��������>.�	��7:=���c�1O��*����9�K_�L��sr�;C>=r>U�8d�1�f�{Q������@�/��I?��Mj�[����aK
��	jI����nT�<H�p�_
�$�c)�fV2ia�NQF	���6{���NI�1����/>��;5�-&���g�����ul��R;5+�l������Ix'p�Y���"�lj�g�`���y��\�Q�����AY2 ���+��1e���qU��}N��������N���y;s����
�e#��
e��4	q�,�(��2'6�8�}'F,������2b�C��Q���u
8�]��ml�pn�2��bNN���A���k	P-PZ�&�2�hV��%�Y-�d����-���r�x�sKi.�\;����,��\�)%�R��)����XJ��Z	Lm!I���e.	��q�R��e�G�Z��^$l���y��(gq{cgs{{{�|������_���n��E��l'K��uP���0��Y���D]��I���ag�5������Y����6�l7����8��>��G�t0D,,'5�Us�f�evzg�n�u=C7�b���%49�wL�uy�����!���!KO�	��~!ob~,Gb�L���Dg��,=JA�	�b�>u��w��90z#o����m���+_r9x,
��~Q@���]T2��_=�^(L�0�I�>�9OJ�)�O)$*�]��;l���YDo2��tiJ���bE���%p�
����yD�e�MW����l�pjW�th3C�D�.q.�����
,yz�������s��dO����C��7������;V���(��/\C�h����P�C3K3����Y/+SVK�I�Z	A$k�R�I����4|�Y����/�o��A�F����:z�7�9N�uo�`DV��
���]��gd�������.r�6������w�����N&p���y��y�z�����-���7-��T��2����`�3�F�����,������)n�2�����Z#�5��lS��f���u6JV�F�^<L�:e6����o�nZ�Yn|pe�Q�w
@��fw�������~o8���Dw�D��������F�����T������9W��kE]G��gO`�?L�y�~����z���������kk{;����p����d���d�%���Fm'Z�OY����+8,��l�9d
A�mZ�~����~��%��F������j�lo�6�L�W�����p��1Ff1��U0LwUc���Q�}G��8�_��^�D������:���W�����xMq�����8�V���7��z�r]x�*A��'����#eUcD������`+^[���v6��{y�3���#�*�q?`�<%��xp���D�*����d%N��^�^�z�=�%���j4)N��{d������Q6���h<M��R�p�K��.f���_y�02���Y;�D���*��/�B�&���P��zms��d�6&FO����Y�����R�?kIyfT�J��nW_��X�/qYZo��Xmy��������Q�E�G����u��.6j>��u�c��qML$��O1����c�?7��D#!Q]gU��Z��,�s
R9����h����GC�{|>�%s��NA�lf*#U����tU���W����S�R����o��+�&7}�c43��^����7���vr=4��o$�c\`p�}<�$���bFB7i�m���p'��
�#�N��ks�Fx�
�����~�;%)�81l��7JP��8�)&��G���V�������3N�HNe{���F���Q������C�[��I.LX����7�'��<U����������^�V���Q��J8RM���e����0DEB��l��v��h�JQ����!�%�no�f����%U�:���O�g
	 )N������a^�a���h5���,������D;��a���w�88�a
�U0�����z:=;�t2GG�������������*����:V��
i{�J����n��������5:S6��(�i}�����Z&s�<�d��1C����(�	��H���,���wYU�C����_&�}!e��>�������iv��'
��e���#ds�W���)����_��>�]F���4��L�K�"U]�m+X�k��g��6�R ����
��Cc���,y�@F���.�s^f�LQ�C�'�������;e���z���V�|[I�����y\����#t�Hs�n9��m������}�V�w?+f6��
��P��|.7�+\�e������b�Q�mu��Q�(	���'7��0�?��1D�dc�xL��(�Io<R������T�����=R��|�q�?�������o��8:��%�����)�a�����_$`I%���:CDb6n@5���y�Q�(x�	U�d���������/<� �+26������\J���(<�J��q���j>JB�������mml���4_e�x�`��|	�u�.PUS���g����������{_�B����xH�y��	!#�p�|<s��*�#@�DjJ�h�g�����Bp��xr1���g
����C�����DDP��r����T�+m[���������+���d0��P� ��`���b�,���jyYB��o_�S�CS�j���zRSM������!�L��`���c��;U��u�%�����}��|�uG���y�2����2���jF9AF�z:-�l�R^R��?���6.�_������v{�!��y��b_����`*d�MV3"���F]��D�Bc�BQ�SE�H�9����Xi����$	P�b����+��g�Q6�����Fjz����)v?�9_����i����x��xN�{j�����Q9�����3{?��O:Xe��d�`�a�TK8}��}B��rB�`�Z��.��P	�OHq� ��Q���"GFVV=����<������bQ������>���=�D�y),�%��%���#w���fZ��U5����]��&kQ��+�Y�s}��q%���p�-���O�������FW��G@~TuT/B���bi�{�Y��y�����2
c�<
#E��������bC���*
B�&>��f��.60$j�Qo|}��+�H��Jxc����b�=��_��u����}r������v[}�={�x�_�������Bv#���"mEK��^�5_�w�������}���"������������&}�>�o����}�WUh@3��v���A�h��g�_��zu���~��u�s�:��;'��C����|��^��!��|wr���H����Ik��jk�t�F����y�>���M���WG�����R�<�n_R�=��B+������jwZm��y�=�==i)h)���'�&�x������5�����#X�H�oo^����k�*��VGI��#>y}z��^?>xsv����/[������_�:j��{��?����Q�99>n�����>��|��wT�C��u��I_h�A����-6?k"4�Nh���7/�O�������C|����m���	��vj�����|~;l"��.�go�����#���v�v�
���D����k���k5����~��D�V���V�G
9���\�����u�
���=��lb�����z;U�j�t�<�Q_��(��O|��aG7j��l��F�V�G��`�AH��G��i�-vWv@`5am��E_6�HM����]�����D������ _��n)���y�l!	|�R�[���l��a)^������'?�X^��)���j���ME���GX��g�&�|v�:z�F��o�i[�/m5����e\�	����qSmD�WG'/�_��+�_x�;�
N���	�'���5������������Fh)���:>y�QO�t��=?��)�����B��
,�v�V�����&����??�|���V��k�qr�O����Q�N����c�:��Wu�/F)�~���?�]U������4����G�g�]QB��d8���o���o��k�?�S\������h�����WM�����:):�����T�H��N}~zvr����=j��??@3��U-E��_��Ha�a�v�����x�no~�S���������������+s|���|Ws���KxC}i���
z.��z��y��k7;�I���Fj!O���=9�
pr�����UG1L���J�-��*S�4tT��w
�Dc��I���PM�9�?m����y���;��XmL�{�w��v�k������(�'m<�#E!�8��j�3��j�/��g��P}i�V�4p�R�Qh����?��b����������N���:����oN:@��3��D���4[X�s��T_��R�o����5_�Mu�+>�|U�B�2E=��������O�������&0t���k�8U�N+�z�@�j�������?�O���,L#ch��`@������T-�9����0p��
`�"�����T/����/o��L��h�H�
��'4���g��R����6������n*���b���Q&J8U\�3�A|v���!�������L�;���w'?B#���S�����-��k�7�`���v~�D��w��m��8>T���Zh��������7�����������@�Sa"�[=k��La��;AJ�,�#��1��^ �r/S��-���P�i��\����	�dD���v�����t\��o�?�qv��6��}�P��/j`���(L�GQ�c�|;�M<�����a�(R�y���|�����e����� vA���hw��~�\���'o�A"T�y���em�4�_�B��{u��n�JS5-�9�s]}9Qs����j�eDI�#!T��?x��u�����*�E��;Q3����8>[��8�/o�-\��=X��������!��jQo�����q4��������TH���\��(��M�^��>����}���c��~��q<�A[�pQ��Wj�G�Gg�zu�<��YV^6-rkZ�YAvy��'p
���h�:����}�qF1�����������:��
*�nyJ�-��N�n|�O�z������d?����q��r9�������d:�%�t��jT�]=V�H�[t�����:�u��/-����^Z�=���~h��D1h�=�?���j�����o�*�'�+�k@��!h5��$�9a�W�<S�v^��	$3�3�	�"�P
��x�����s�D(�v�d�"�����B�NI�O(sd�x�:-i1�b�O�+S��QM�4��v��ht�}(b&XACj�kT�h�I�����:W7��hu`����	���$�����D�um!O�e��7+�D��~c?V�����*���(0�w��PI��<&)��PK��0u���?G,Q����N��X�7�R>	
{���y"�P���#������"�rj��m������s�(p��TTcw�u������`��}]q�2��+�I���LW1Ecw��Q4�6X�u�.8x��_��Q���C��W]C�[�c^���.���\S�T���9��e����Nl��[����o�_��z�K�Y��\����v������g*4W��������$��>���1�k0 �w[|,8�~��/F��a�*�4$��6	��8�H}�V���1my�S�����t���G��NWh��:[��h�
�%Si3x{�{����'��
?~�MVV{��5��m
���P�:t�x��$��������/�{�������UD&�x��D�'F�Ey��h�5 �S����&�}����gZ���P���2����6��kUo�w]Z.����?�[���k�vv�k����O���g���Y�����������	�V;*s�o/Xs�m���
D=j����~���VM��p��!|���IDI���X�����K�_��H����ME��{p���!��7x�����d2���������8����W������o����+kkk��YI�i����k,s����X���(Z���o;
VNe�B0%a,`?��E��)��*D�M������}���R!�_v2���~�����D�zggS����5P����?��!d�%�x+t�h���`)�p3w��x��Q������A��+���_�2~������iD�	���p������(���(D�~)�<�&NB�@��l:��C�I���!���������G�D�iM��1mI��l,���z������Vk���U1Jc6�D�0�t�"^'z��1�$������,��3#F�o������EhN/)r�����$�}��d��j����J:��_�U'��v���e���&+�` �%*2P��e����1����c
�x�9��fc����q���>�&������m�-;�Y�?Y�JU���`��<����|sw��*du��b���07���5{����tl����6��}���U<��O�A�/I���,����t���w@��9���K�Nw\�Y����U>�yV�������SV������9}S�F�)]i{O���-��o���	�)����v���MYU�p�]�8!�=�j	��D���������-Q)$B�)��,5H�*X�j�mO@�<���l�laRAeBa�~�� ��1L�D���GDtY@���c�W�G�H��C����x���$�&:J�UI�N��hw�D!
<�kqpkg?��[k�����	������K-�����)������i���Y~$�B�Y�_$
��QA9���Z:���A�sT�z����� K@�NV�A��y��@�vz9
8w��+C���y�EH6���U�H0n�pU���k�������z]���nQK������iM��~��m�4�J`������`v�mE7nO�!k��C	�,��t|�����$����M���6�`j��M���}��O����=$�v�-��������W�sB��������{cJ�KC+R@9z{+����K5GY��c�������f�NI0���{�Z��4]O�YO��J����+=�H_%�`�QF��U^`��?��D�|Pe����OS46�N������.��f6
1�^������ S�TC&2��[�#%bx�������'S���C���A1F��	C���va���
K�e������_�����E��za������HH_Zr��|��,&����������7�V[�?��9��o#s1�GQ��F�9e��t�l���tJ/�j��@��F���r���N��s������f� �f���]� 
;)����u�����HF�`�����!x8W�h8����B�*����fi�^�B'�>{K7�m��K����R^�����eY���{��Y���P/}��Ud�#�A�'Q�����`���Q��mz�%��v�<0q�b�jLgs-l��<�������w���U��[������lt�����K.!�xQ���%7��|��'x_�x�z�<�vp	��4O���0�;����j���Me�����<a�&�P1��v�W��FaA���,Ki�0�E[O�L�a{�7u���7���A��^�e��8����-qP��"oG�����	�#����Rj���N���O���b���H���/�^,���`}4��v�^]|��52y�Lw)L����a�e������ul�����H��1+�<I6��*	��X%������A9�{�v2�,�n�.����NH'O+b=�L��o��gA�l��M�n�7�$aK����5����b����l�&v���e4Oo���s$4b.�w���o�����v���h����.d��=V�/J�y��2���w�$�������]d���$�$��{��c�s�D��l$/�DD���ua1!����\B�	Z�zY <{���g�/}�L��/�x3w�6���N�N��T�����?El<=Hr�A�.���r��e��r5�BC}�rJ"���5�8�<5�.�7i� �
�7�;K��1�b!w�'�;��H�U2����L
 ���%��	
0d�C�j"3
��0�):������	Q!������4<�b���g�2g:?AjNA)��v&.��K��Z���y�����>Es����I��%���
����hxC����=a1�mD�-�����d����v�e���Sg����>���
\��e�B��
�F~'�:X��I|������"���o3�{&8������3�f'�`U��:�d�L�OVqrR�"�Sm
���C���"��o}�J�vm����n1���>L)�zw2����D��*,���k��q'��������@�_�����K=���@Zf�(�?����-�l����?X�@�@6� !�\L�~�:����(��8����{�]�t���:&�i~;;��#UeVK>��)I�����KazKs���-����O����7��)4�����e��i"}d�����T�/�����7���b��b����f���e������-f����IitQ�d�����~�C.���_�D�����K���m�(�C����Q�q1���`ks���l�3 ���P|�6G}J�i�����0���,�f�a��/�7U��n;�
;3����6?0
"�ok���hp����a���N����x����4uD�f��#7�O�����
�`a�)9w�:D������+D����/.�@��'�B��
������!�x�"
 �?~���1���v��#�����/���>;��:f���{�/����l�xfb\���z�"�d�����_�V�2�niDZ���5�j4����;��5?1���6����v�N^���Z�����C�������d~
q�U�����[�?���d�Q|�����z��G� ��Gy(;u����Y/
D��_1�'~5�*yt]�),���6� ��6Cds{�ho�maB�������'>�	���~Q8B�.{�no�/�m��;&�3��v{� ���[�[J�K=�����N�'���x/���|��$�hG:���<�&�����x���1�W���� `m�sp&����
!����� ���
4�1-0�H���'����@�Uo�������:Gw ��}u�v�p�~�Sq{}�1hG#xV���9�L��<����k�����I���������s�PT��3r���H	�s�>�w�k_���H�����N��|8�6������6_L�w���������9�������i6s@��9~|�6�H��w�����+��+��6�	�w�u���a|�|{cc��QL�8���e6�����6�3����#z���+�S_/D���T`���(�aK!1�<��p�Y�g��TdN�(���kk{������`{�0���Xfz[�"��G(�%����	�����l��J9������t`Ss��v'R;y�m
�%T�p?�Z
�v�C�u����jo��AX����=��C�-;n��c�^�
����I\�lJc=�'�K����$T���|��;�h(�kmmsWqA���FY,��
P�k�E�Q0bL����&��qQ�a��x������'�V=�%5U�gS?y�(��/�^]��M����W�j�z����S6u�����s���Ei��7#V�w��sN�l>���MG4��9��[5��ex(-4������=c\i���n�QOE���z�n�~������������S�s�����C��k��p4�1�U��h�+jD�����V��dlH����&�bQ��`;N
E�@�n+h	����]6&Z�����V�SE�;��]����3���-����W��A����`y�Y�za[2�`Vs��*�oO[�f6&�V�[���YM�[�w���LL���DD��Mg�����2����J4(��ac��C:*xw6��E����g��#&S��5�	<	=���4���<���=�+�8����g�:�6[�-���`��<���5B�f 8HL��pL):E��:���W���Pw�m8�]pm�|��7��t�&�����Y� R�3=�4�,3C�W�_`8b���d�lz~���3�+I����[�CM^�z34����2�����%�NO��mqW�0�ue���� �e��4;�/A���$�/��$��:����{����\F�ar�Q��U�\F��#�Cy��v]V�D1������+������e5u
T�i�wQ���������6�oC(�:r�f9�W�0��w�����oy�e����Wu�������D�G��H�h�����M� )�9k�����rtR��xb�njR�r�Q��j�9�Z����+`� ���a��
 �<�9<:�/��D��d�J�f?=�@���A�?��l��;���k�����5�W���[?
z��b]
������"j�m�(�������~
��f��m��M!F��e|���s������F���]����N|gK�&�����;�L�kQ��(�\�Vx}�
^JFw`�� I�I�l5kQ�z=
��
!mr�Xs� ���w�\���5����'�W����}�<B�����w�
���p��T��X�+&�	���vT����e�X&pv��Z��Ax���X�Zp����#M�v��������]J_��B����xf[&���v����e��?�<����_�0�@X?��
�;
�p�@�rH��H�� .[z|=�
����,������S5���5To@������)U��TT��3��$W>��M��D�:��%�Fk9y���`4[.���S5��
���AR��3J�Oa��6}��`$vX���7S:�sM	m����\=��y^qm1�*A��p��������Y-��z�h�����j @]U5<aD��Kp8.-�r`�/�3+����D��y<S|�=]t�c��%���#��8���A��OM�K�~�Y���d!Z��|����5��L#�`�Q_lsxv�?%����
<���eE�]�	��/���1�`�<N�a�S0�����}�������o;�}
�ph�T\8�0���V[���;CmMd��&��W���Zj�Bt2:�h���l$�P��r��0�L�A2Z�o� �)B&��=u�}5^)P?�|8E��k�z���/���\4�G~	C��D�\���,���!'@��!T�S�_
6J����c����@I��2HR�KB/�h��J�����_^e>���WS����K@2m���	'0w�899r���;������]�����}�>��A�W�	�)K?��#����}��X��������-H`����m�����.�?�`W��b�T�3Q�$�K$�"��b���Xr�Mh�)�����=S���~�����K���T�	r�A��� m%?�Y�?~Q$�AqR��p���|:�H�h�
�*���
1l����	|���C��!�8Fz/�l�B�T�8�0g��
��52�]���	 UF��x��kG��<�T��e���DC
F�
���G�����|��`��Q��d\\�'d����	-c� �
<�5E��
���9��x���G��hJT���&�8��V�2Ij{��M�gUIz2/��J�@��������a�q^m���`�>���H�a+�����B�8�B3;h�����v+H����������i��X���8V"�
&���V�����T1�������$���t4�� �%8Ur�0`/5g���p��59�?�t��:0�,�g�����b���&�j����A?��Mv���V��Oo\R$OyD�-z����.|j�� 0�.�`-��%�R�T��*3t+y
��B���)����M="^UIM��i�sB�1���[����
5L-0G"��lJP�y<LU�����
O�Y�CJ�r�y��o5���f��->�"x��J��z���I�)���_Z7�b�}G8�;8���"9�����boF�7��#0��j�;p�P��v����m}"9XAt/�k���a������p���
�����M^=�2K(G4�-���Bi��j��Y����	)�r�_��#	�2��� ��L��&d�ov�,l�9==9�4K��)�CJ!$Xb��EnX������ ��gO�
����Y�F/p�P��Yq#��O��5�y����K��'[�$�{7�@S`�HSX 
	��C��������	���s��{9��+�����;%�)�V��[��������:{���������p���RTt}�����/f��?
l.��=c"|��H:
N�LO�pM�~q�.:T�(!�b�:9�3���|k���p-b������0TA��GpB�r�{	�������N�^���m��H,s�r�4%v�>�@�����_O�{�K:��:R���5 a�����\��9��{z�-mv�
7�nvN^��$�m4�zg#GZ
k������N t��	B��!��Z���*��C4��4%XU�R���Dp�3���s����l9���P�,�������N�����
Y;�g#%W��������v.*����{!R$ls�R6=���l[�Z6�� �!B�n�/�F?B�$"$��X�q�����x����������E!��`-VjOL������|4K��fU�[4�J]�b;������z694���$C��|U����M�)����[�����s��"���.��c�B���~��'T[JC7%���m3:�>��B��de����J�Uqb��S��WI
�,�x@
���<�����I�R�� ��������,���F��}�5���k*������l
4��7jS<���2�-{�Gc�r)��ErUp������l��W��
��,��[@9q��x��^�kO;D�F��\A��� "o#�57�xPw��9Q�AC!���E�/=��iE�%4�2��
���?�v��m���1����KA��]���sR3�q�������U�:�w�w%��YwL����[�\2CK7�DJw�����������~~9�~D�P��8O�b���)�W����7�Z��R���A�~���x%�����"W&�&^�4�;e�]_D�^�����_�>�2�e���2����A�u�"�#�[K���������*jm�M/h�w��]
��Us�]M���9� ��U<A�;&��-"�y�4v7�>����-�����dm��K_20���cI_dQ*���@V��c��d������c����o�Z�q�%���"L�������Z0~�T��:���\�����J�kcMv��O�%AUS��i�����^��{Y�i�Mo�����R�D�H+�U�gdITiX3�.��9X��]�s�m� �0C@_��O�&�kQG=G�.���`�sl#�t���p.F�6^LZ;�X�G��F�"����e���7r����`Mv����#cbB��5���XM��u�(��>�7��L(���$[�g��6�� ���bt�K�����F�������%��\�����"�!�������?�>W��&(�|���n�����_�����,V-X�V)�46i}��\����3qA��o�}�99��MN�Pzbi%I�%�R�l��%�C�0�V����L��/��F�R�9H�/U$@�FTi7� ������
������F�Vz��*��w�� �Jd�y�=����&�1���X}�g!#��11A{~��2JR��4�X��7����\��~��n|g<�%Dd����E�p�t�<*����Vu)�ME��
�|0�\)x���x��H�@�b]�)������PH�u�jx���`z3!�����:�F�6���x,]���	o,��:���X�����%�������L�w�(�r����������P//���G����&�ke
�e:i��/��$o�kI�|;���-�b�G�x�����"e�zg6���,����������n[0��i
u pM8������1=K����}�:DM��B���x��)wD���.���o�9��x���H�#2���t���X�-K�Vh��.|h�e��l�:�e�\Ka��@�T�
g='�������������I������E].�8|�S;�����c�s�C�!x5t����g�j($�;%s�Y��W��M�����u�
���,'=q�,�ou���q�)c2�$���s���-�Gu���p eywfEr�����o�Be+��N��������I
-��WWsR�`�Z���9R�`d�l9d����L��Z��I��-$~�7#��0D44uRq1
�����q����a�e���'y��\��j�%z����O�U<oM���!���,�A"E����7���BD(��;��\���N?�����	�~�2%�A?�S�>z��U<���B-O`����-=�"���B���@���8����?������D��A2i���������Z�k&v[S����9�����@��H��E0�.+cW�S�����xJ�����J[��&�jIt���qq�N��H��e�	��d|�n;1��s��YI�4����Z^BUI��p�N��p�
��:\E��{��\J9{��q�>R�Ro��0��8Q�2+�E�>��\� O$�B�&�*���(O�%��z�%�I���n��������7�(T�6hj'j�������#��J\�hT����[!���I���P;r9�;[�H�Q��7���AV9D�Qe���S�G��T���Q7�w}r=�����QK�������w5���#��9$�t�)C���;ER������c�~��Hkd��5�����YJ#�~x�!�z�D�Q^���g��S���*4������������F�����~�fF�nG�m�VC�nR?Ci945F:�b#�/�Z�|��W���TJ9M2�����f�����FW�V���2��mT�F_k���B��,��e>aX��"/�`e�,����`VDMiLC(8����������2�/?�\^/�{�^]�����K��Md	��|o�8����e�S������|`.A�\�=�q�%���_�������������kk�6�	(����W���I-2���t/��R�����d����:%�iQ7��Y��3#��j��/��y�Ll�3����^�@^0�������-i�;/���P�?��/=�i��w.M����(;���t�n�(E� �>��iAZ�7�W��J����Z����,�����X��H������p	�a�R&5B^2���R�I�%]������nv*�y>!!��U1�y�*�'�K������wX)+��A����@^#���,��.���yQ����(u��\Q�:r
Rm���u^0=e�_��q
�nop8u1[D4pH��x�DOJ�l:�7�q����N�����t%�>�Q������j_��jb�x�L
���^C#��.�YJ`�b�����J�q�0�v��)��J�XM���5h*X�v���d�o�3p�q����B`�D���I��I`��z1#���i���k��!��%]�o��Vf"D?��6���S��X<��Cp��f��!&���Z5Eg���p��G��:����D����1��`�C��~�Ym%���q,e��
0�W�e4I�}�s��8�)�\G�(�W�2�2��H�P����{4r�9P�����x8�7�
��,PS/t����=���8E���<Fk"�����o
f�$��s6�����\����0�a�n�`4'�������B���rB��NBG"���d��������-��\�,�l������aM�^4����urF;dn�����9��L��o����'e9�����
������)B�[�l�SW�O���f��>�c����m��x�+�[W��B�AQDs�a;�Q�*h;��E���Va��&0�dg�0�t}����!�w`�|$��4���@���\�����,4����_�M�3~?E�����f8����"n���T��0�S�G�2&��,��l�J��>��"�8w�n�g����O�eAJH(�+��M k%�g�VZb��^M����@����&���
3:X<R�1E]�k��C
\�F���7�9g�������^��[$A����pw�5��r�F��4+9���~����EiW���#^q�a�ngtgNM�>9Hb{�Ys�h��7<e
w+����2�
������_��9��3 Q���U��h�,�D����Lf���8�5�b=���2*��}*���:*[��8f�����"W��[���#��~]�7Wuc���� w�i�����=�L�[Rn�n@/���MZ<�|����c�b���2��V��8���0��V">�Bc��"�A���;�e%7�<���T�r����J����3@
&%������ �"����]�����"'U�B �kq�ba�:X�����c������sY��q28���xkv=����x�����
�
H��-R����7�p`7��9$?�zQ��I�=<�U��?�d���`?�/FM��Sq�{���q���tH�;���|=~���Y��b���0�tw�1X�~'sy� ��GF�����6�w�&��Y�����t�(��FQ���������v����rx�z�ul�cP�!���	+�1�(,�M�<��hj�X�)@�+���td�eP@*��h��b���t\�}��h���0��\�i-��O1����������P�$��*C�!�
yED\��S1��jx��p�t<3�B���1-�&�c��S���z����j�7�>���z�K���"�U�L�I����R^M�.i&/6
��0��R%?��F���l&��L-qe@���T��K(�N��P���+	�Rq��8��6��k�t/�Fz1-���y������-��4+�����Yd��}��@�����FlQ���VpQC6���Q&3�x��(j*�}Q,B{v?�/��2	�����h5+4����8:��������{V����|�t����u��m��t����kr-�9��FQ���O������"��ddHx{�5Qoc�t/���6��UUN\��,�[[�A���B�KIc�:�K=��~����B"T9����,R������ci�'��xL��~:j}��,�|�����6^XF�`���*8?�����s�uO>����=?Z���Q��{AU`��u�X!�HA�a���(�D����K�P�0t��'?������P��#3�����%�c>���(?�	U�Umrs�F�����UT5qoR�Y<��
��z3��|&���3����5��3��Z���������n�&��zE�IR� �!#�?��T��\�G�k}n�E]�pw���
�3��� xA*gx�t(����+B�m]�f0h*��y�;���F)�r���^�
��b�X���o��h3
a�Z)*��W�-��.k�<O� '%�)��J_H�Z��14����n�Z����$+�+���.s��nj�Z[�5�O����_�vN���g�Yj�������j��6������K��Yx������o#������]0�v��w�L$�>+\N"�Y�I������*���c�������gd�Y^E�i�6�D�n�w�r'�}	i�T����{�`c��N;��_������H����)�x����egjKU�A��@y��AU���.��A��T��\����.�-�W-h4��R�}XZ8���UpP5<���?;�Y\Dd��w3�.����	�������Ip����L���/0JK��� ��"uvF(U�l:��a���O��xdj4�Xn�dQ�1�����Q��D�UQ:���)%�<2
��6�n�/��w6���SST@�x��H��t������&2�{��Gdq	sT���!����y���j��5t�$;a YB��D�o�r��\��~��������JU���H��Is�yS������9�@|I)�7�9w*�e�H�����
�
���;$Nkk��M�Rl�/�����#:�n�`&�
a�)L�a}��9�Q�'w]�D��`����������)o!��g���"�8(��Hw!��~&���Qi���MA��V�����|�|�f[�r1���z�c���"�+��>�O�f�����{��������}�o$r��bP8)�6�R������!K����I�����v��z��9uy`��������Pu��G�g����7�����U�lr�u������ZU��!t��fY\U&+};��W��L��y�"����.�P��"�x���N�����Gsq��gt���A�]�P���$����QC���N��<5�!&�d�^��MRb��(y4n�I�����B^�Ki�5�K�?�������<Z]�)&�I2<������	k�����A�/��`4����x��?���]_[;��[�7��7v�����������2�=XYY)��������nm;Z����H={9������I�&�1�L����c�"Vuv�?]���z
��k5��+L.Z~�e���gFY��G���-5M�,
�����!�n7���&$u�"���P*iR�1
�V����i��O��
-}K
{��"{�&�S��3��A7��1�	���N����=�������~lssX��7�
��/��7�"��
fX�yx3��e�A��R��;����"oIF3��+Z����E���dm�K�f����l
��~������������W���
��L���u�^�chW_�{{;�?U��m�=+_���o���"�����AUE&�yD_&�Z��M�����!0)R1^j�q<�Pb�� w����[%l�z�p���s
����G+�a���Fv��N�thQ}�<�[;m����e�4u�K��Y��'`x�'g��cu�v��@����aR���g\d�����F����Rc�h�U����P��b����Z������D����������p/�������u��>������n��q��7�?*�������o=�����6�v����w�7����s�_Vk�}�U�n�n�����A�F���F1�W�'����9�].�j���G�$Xx~u1���X���oV��q�;����lF,�/���6q^{[��&l'�jUX��+l�w�`�3�������h�����q�i ��[��H@R�Z<�>�f�`P�����&Dt[�����1\#~�>o/��^�����:P�H��[���j�]aq
7U�=���7���N���V?��=��6v��	n�xKpE<�����z]�Q�e�pB���x50�;�M�� }uA����m7���O�
X�u-��H���#:�b����.��v1�5��^�?���$�20�;\Z��^w�!��
��?N�����j�=P��t���B�����Fm#Z����R��x�����x��$]����j��PS�vN��?��a��K�U�$�.����
����@�Pm�+`���f�E�T����9D'��B�/{b���:;�Np���5>�6F���=�S�Uh<���a�Rq-�����������L�Z��1
�q4�?FW�x�n��b��z4P�Q+���E#���I�j=�C^����bQT����BE�����MB��3�Fu��VU30����JTWx%J8�����n���s�z���}|�q:Zs_x����S1nc���h�)����o���9�g���j����e����b��B�<Vl@����Q��2�S6��d.�H��C��
���NCB �E�����������!1����JA�!�T�Dsc}�k��������������2D���#�\	%0
+�o}yX#q0_O����%����
 ����^r��|������^�"���������{�����{:��}r�+��Wx5R��j41�N���l��6��T�y�CxE]�`U�(�bjp�@t
L�F1G1CH4
`<��(��]�au������"zR��}Q��������86�R�,
6�j|5b�~�2h)���
��e_sA�9�Qi8�'�G�G��������2�D+9�	�D��_Pu���oMM�G@R�b�(�Xkr>=Tx%�G��3���7���/�0�9�&^����w5�4��#Q!�}%����9c>lMd<=��pF��g�qx�����pP��]�PlC{���oV���D.5�<��H���8���o���_��T8���1~�x�����A<�PVm���������5�3�Qe8���~]`�tc<��R�7�,��,����q���v��<G�<���^I<��b������$�+h��`�4����_l���dz�/aj��=:
F��mJ�s[8�|�<�#Q�uBBB�9;!ps0b�)�z^L�;�iS���R%�
����|<�?=�'N��&n6;����Y�����]��7m9(�5|a��<h���,���x�����4�1�gu)�^��/$�*���y�:oJH:��e8E��������E^}:V0���bI.s[5���^m/Z��$�N�I���#s�V�M��@�+�2Q�����

CJ������o�k!�!w��e����`ap��>����^�q�X��yX�}��C�\�^jQ�M`iQ
c��U����3-�k��@TP�(�Lg�3������m��%lP�n����O�\GFu�A������!�2��E���8i�EQ�
��{�z`J�s)�:�f��-�C�R���H3���n �i��#-��
�-^���"F�DH�4H67k�����������)�@&FhO:Y8;��c]�/�j���J��P��������.��3�D�Q�U��Pg����
�f.�bo���v��K��#j���Nq?���w�	�^b[��
4���A>]����h/e;�g�&�Y�U�#1�G���^{������hO����Sy�h�y5�4`�����?�>���}y�@]`d:'�'jy�2��59������U���Q<f5��j`�@v���l���9��)��(t�����N��;�#��x�c��0/z�i�0�J�����2�B
���vg�OW]5@5~S�w�gWTu^5;������z��"�6(�9H�����H�����c��E��jz���y�g��#�ym6P'����LS����I��W��*R���T����)4rOt{E4DK�o^p<���!��6k�
����n�#BM���R����I�K���$
!������U�o�P�Ec�P/�~�O%�
=C��H�x�|����4�9��+#�t<�����m!���C7Z%�++�o	��@),�jP��wz�:�4�*��(F�E>��
a��Z���_��C����>��t�Zo�A�����������T�
bZ�<��me�Q)��1����(� � ���UVjl-�����]-&��w���qO�Xz�!����K%�$�p�=���
d�G2B>\P�/���6*��!�W)ZFI�"���ACL�m:,�=!���U6��ac����z��U���A��D���?��i��
����P��M���a�>�)�����������<�
��G�V���C{wk�VWDwoc�Vo4���w
Jj�~J�������e��?7���t1etP�������K�&�V���u�
�@/�>�R
P*�%�:��Ti5b�5u�����6��w!O���
6�������������
�fq�@�D�x5�p�;����(��7-�Z�C��-���U.�<���S�y�����JJ4.j�Q���0�������Z�����4G�7��_���h�S2y�z�e����
��k?�+{=�kjMW����|��7,hU�fc��&#u��J�q8���A�O:�w���:GJz��iBW�U�+������M��I|����H7�TXrS'^�����y��s�#3Uh?�[E��	��V�Y>�^��`+�T��F
����(�6���@v�G������@��C�?5����O����p_���;�����c����
>�Z'�E�u����������[�{��}��>f�?+���7�n`	��Z����k,�Tm����F��AU�|@	�������4�G�j���������z|������r��bQ26�#Uc�9> ���W�u�-��~�E���=T*?n|�7������EFAO&���
����H�7�����TQ]�C[�?(+d�%`!�JNV���06���Tn�n�\	b$�����J���b0�l�B�����������z-������<�^�"_{Z���:B}BR=�w�)��&�����tA!?�b���@;(�[/�,_�H�E����{���<��5��N4p������'�[v>�����`r<$#\<�c�B�.^������_�\aOL/IE��rl�&~]Zo�� �l��}i)�"?�%��vt�f��jJ�'��9{�Y�@=�F^NEZ���=Rs������]d��X�(Ph��-�����j�{�\���u���Q����_7� ������������a�#P��c�Z�4�������������bmz`K*���R-��F�p1�rJ�I�������>�i� ��B�|�M����]���R�v��+kiK)����
���jF�`��U����7VL���/r!Dj��r������7���J��[�,�pd�<kp2Pw
��Z���b���a����G�p���m���b���A��C�A�n2e�8�`����Ln��V��"}x�;0/�A����m�Kq�BBg��j�X�^](H����������it��7��m�������r
�W�0�_�N�!�s7�F��/��@�����m��N��S�m6%E�U��<[)�f9v�Whf�Z��5O�*�XD�z�~�M�nK��-F5���l�K��]A���5 ��x�j���Z|o�\U�'s7���t����IE�D�~fj�)8g�t���J����D��z6����KG��7����I��x�ug�}�Y��L��p����x5�����������M'*�K)��Z�U���P���|����8����.W�5]):������M�0�7�����G	X��l�����^^\e�����A���T������,rt���p����	�����hl�&�`�S2��x�Yx)�C���sp����#1;r��G�G���M`�P{�(e5�g�Z��6���5@����c��o\��Su�n�d���8�i;�o~�&�k�-�#�����E# ��u�[`LA���x�����64J��
A=r�������lqq����������q'C���5M���BNZ�Yj~���Avwex$�o��a�I&H�	�	�������Q�E���W]�������DJ��W0�N��c^��K�
�*�'�R*������=�WX��5-l��F��I�-���`�	���
�7����_��VJ;,�	Z������;K�d0���Cr�WCc[T����
�����w���<�K�Y�+
������o���F����?�����{3�+{|��:>��a2�rdi���#���34+)�f%���.����������05(i�?�P�8���J��y����dJ�!����r�����Z��������b}6����Lq�_f����g��fE�<��-��S�|>�<m����2��7���O���G(�eZ4kZ�����.G�*��Q_)�"�):���Eg��`�9B�Z�rkQ����8�����K����� �(�����?�$	S���$�"���d��c$}~l������	1 _�d���S����sW�Y2��uo0�V��o���v�m0��{�[��1M������K6�]����E���/��Jv����)=y�!�6�p�x�����w�\j�!k��������{�M�T����L4�h��xeE�$�jy�����w��1�����~�R�����Ufb��u=����YT��YQ�MKoH���b���%V�_�~��	�G��f<�����QX��K�0�����<A	wil��3N7��D�\�����r4��J%��6)}.<0�cf����AbdS��@��h��Fv��a|���S�x��q���u���Kp����`���"��-�P����U��}:h����6�m���ldtP����1=�QS1���wd������^#��[b���-0Hcb;eYBR})/y�_K�+�����j�S�S���w�� *��6����P�1�
��0���c���Z��o�#)��a>����:�����f�m�8;x���X�D�
����'�4;��hd����s6���P�H���[ajO���z+5[G�m5���%b<T��a������N����>GJ��������v�vY!�CG���U��wu	:^�������]{��;���|�����c^C��){���[� X0���V�
H���
��KJP�:1�,�E�v2w����5�Y���Hn7�A��i���n���M-��=����X�E�l-�'������j;������2�8�w;'�7��i+w���~�/������x���W_[�������F��w���:�U)x�������o���x�S�{q���/���4����66P��I��@(�~kbb��q�I�a�k��>f���V�^4����-��7�F�m,<����{�,\h��{BA?,������N����M��Kc���kp��D'{����^x��J�b��g�������F��lBx��T��@���-�W0�����^�B��#���t���D?{Q&�Y�������A�xg�����q{��0�����%��
��������&c�/�Zr�"���y���S���lx��V16�T��4�d$f�H�A���v�PQ��IH�sm����*
S�1���
�[h��3M�v-�Bn�i����#rr�z�`�����
)e�d��jZk
��~d�j����e�<�����.��_2Yz�d$+�H���O��Km1�Z-�IE��WB�-%N�@�5�o���z�2��N,�1��B��3b�e��_���q�Z.�(6P�"���������Y��pS��`��}��q�TRU|A���:=���#i�����������Tu�������%��&O��=v�$��xK�������#�u�5R�3<�^�9@N��w}��l���49��������O#A(�bo�L��,��Y����������+�Q�2���)E�{��,��J�`EC�������
9����&�D�x�QD�7�����X���*q��W����rM?+�+�N0
E�$E���m�����X��&p"���x�i�wO+�������y��9O�	#CA\�UC����7��� �jw���Z5�?=RE������;<�+x�U��y�M9�#9�M�94U7��v��-�nl6$Vd�S(f~�� �s��
�������
�n�������(���}E	f�Y���:����>��ZX!Uc�am��3������x_��e�n� 1�&����;�dij�c��*U�GJ�I�m����.��������Q<G\'�mN1��=��m���2�N�]3�y5������:]A�|�\Z���H�ZA-��^t_4_��
H��HWw2��{/��&8�.��"�i���	�m_�$���qF4�Y���M�w���}E�X�(��"
^o�AN��[��kP����x7|��T����Bqb��b�r��j�]^di���i��|E��C3��T��%6���M���wV��������!c3e�a�1c�xoAc_dD�}���
<QO�EF@�yeS�����/�5���{*�";��K������Pl�z}c�B������Mx� ���7Sv��z}s���A
v��V��2�_:�lA����-v�n��
<�]��ZV���Af3���z�K���������h�E���E.`{L>��az��`}wv�J���rk�[���;�ZC���g.,�;�j���+v���K
"T���{�kb-\�i����P��c���SH*T�vT�[t�{wb��4}u�vI����8����<�1K�m�7Z7����f������~�;>u��>��Q_h?�����>�Gw<1���2G/8)R��'�L�+����}�������^mk=������"\9��kS��oS�>��2C�������1�/�G�d�`i`��������'�uX
����y~$�w-�U3I����Q�����D6
�a|���PTXL���}��!����$Z7L�EK}�nn�[[�m���fx��g��V�����#��3�����h�mj���(��������S�����(�kj�E�"��A��^������a��c�JZ��c�~H����\���q-�����d��)�@�"�����g-�d�|�
�}�XA[ds#a�*�j�}�&`�g�c�T���<	Od���"��W��{�}H�
�!����56�h�v�x ��E�"Ua����!��wN�;:',�����5���m����l���].a�^7�0�p��T~��Q�k�����#=�"���\L=�whw�l9�!�����K��@�#Z�`�9��Z�E��_�k� .t}{�C��y�->~�v������x��\;�9�-�R��=Z��\M2�_9�s}��.�w�u�GXq�ztd�'*4�f2���@�/j��~U����N�/\8<�F	r��5|�����Z���6?)��'��/O����`��;�o�em?����"�G�7������]K�f�����5�bE��i,�mRN�1 �Q����*���E8������(n8��S�.�.3}{[;�����h!�f���eO�/q����]��� �e�^��ib�0��������pW��5Toy�g3��B���X���mD+�Fc��-N����7������jH�h�Y�X�I_]�oY���C$c�c����>nB�}R'yf7���H#[��%��W��cu��aokpT$�=�-�4�x=]6�}l��`Aj���#���Z ��N��d0�;r6���uo4��'�\�~�i~�gsk���V9I|�U��7�9�b��,�I4����f�/T8��8:��rvr����������YE������GMR����D��:�����kp"<��*My�aM�7� �a
m*�'��E�M�T�/�����4���-�v�P����y������Nq�^���L����v�o7�;(��\E������=�qx�����W��������b��<c����}����M�^L$����N'�
z�F��Q
���u~�^s%v������������f���]�n�v���za��h��6���(��^�/�W��D "6S&���y.��A&�������n������Uk�j����������.|7-:�G���S_Ar�^����Vv��FeV ��-��?��.Y�J9$��H�_�UN��3h#����G�����N���d�Y1�8n��l����x�~q��x����k&e��e�)j����D	�������!����� ��<�N"���T>h����nv��fg�=Wvt�X�v���wi�e�$C���/m'	]�������
>u�A���"G�cx+s�1��
($�ml�Q��&�(|����&��7=vZhOg?���
	�MI��Y6�]V�R�+w')�@*RR=^��c
;e!����E�y{[uU�����_��d�b>s���E��#]�<2����S'��_rC!2�'���Q���Bq���h��D��~��]7�5sVu���� �qn��S�U��
^�n����W�#�g���[L}����B�J�i����
��t�D��Y$	�D!��CAn���j8���x���W%��oF�q #���>D�z�,G
���!�:�������w{kk�{��`����U��m���jv e=Z�_���^���t�?���r
��q0�T�0T�s�I!��O��������
����_�&��-��CXX���JH��?�j
��.,x��\�+g���W���]���t�vH�-Wp��@�1��n?I�\����c���G��x{P��0�rj�%����h�O �K�P�^���I�{f ?��(�r��a['���m:��E��K�0�����@1m��C�Px'��'R"�c�����j����pLr����
<S���W������=�R57�it����b�J*��w����H������CI>��Dr�K��@�OZ����^��x_G�#9��QU#��|��R_��2kh��C�i	�����V4��R#0��{��
�"e��s��
J�.���g�����D�b�	(R��h}N�K\*3���)���3����
S�Vu���XH���@`����U��y�PA��t��G� �B�h��WU�@���^vF�����J��O����?���B�������'��� M��kz����H)�m�����0�N�5a����'�ao��<�P���v%���6�sY�����6����w�k
�1"E�tv�i�(�O��Y ���^{W�����F��4�����h[*r�&^9Ad�]${�/��(���m|E/����@�%���U?�(�P�Tk��(��Z��7�,���
�p��Fcks���X[;�l{�b�J�p�T��P5����.��>�Yc�����=�����8QBT���D�}�F���F��{�
md���x�d���P'��J�>�j�m�Z�V�	��M?�F�$���W'��h������������-Z_n��<@���zp�<E���M��\��i����������*6��UTM�1��-IMG��6���������l	#D�C���7��������7T����Gt_PC�w��~
{���1�gDM��N_-[+yM�?��p�Yu`)b�A�\�� h���>�f`S�P`��zF�h���A{
,_k��W�,N���/�g�#�#�!��f�[�M��'�Zl�������a�� �������hpD��U����h~�;s������;�l~���Z��6�
����G��G��)���\u�%2��2�U:���#�uU���p�����7�x&z�����A��Z����\���	��fN�HW�jZUp�8D

�EF=�����
��W�v�l�a�q6����������R@�F�������O�j�����
��#��1e>�=�\�2T
�oG�����������{��-
�KK���zTh��->�"������� V��"8�A=��a�Qf=����Z�����5T���a�!�c�33�%�������B�fK�����RVk�������
�X��]V�������Z�#m$�K��0��@���Kv���:�g������L�8��}
�J�O1��S��� �\|f�9��i�������pw�}91H�����o�~}��9�K��&��<uO���G�hu��������j'���\�)+Mi�)b�9���]��P�gp0�GF�6�X�CCP}�@�Q����a;����T��q�M(^�O�5����a7S~��Q�;���'��e��UV��8�Uv*^5;_22�I�9w�Oe���{w7?)�������{�Z���N�D�"D����d����X�C�������x[�p���1����y��
!�wC�C��3([ ��p��"c��~����=�d�m���/��(�HA}*�O-]'�p@��i�0�H�������C�q
���`>k���?:�|wv���w&\���[	(Ti�vTR�V�q����I�����f2L��'���k���t��5������6}J|u=f;|��������v&��^��{;	�Z!
���H�����6$QG��	�K3�8��$|����u�3S��i�%%O�WtC�K0Gz�Qtx�]�'���jp^A����d���1F\��o!����� ����g�E�iqB�~/n_����pE�8�5��@����YC�����p�8NLFt}����>��x8RI�����n�R�Lg���o��grk�����g��$��!tW�K����@��0�>���F������3��x:�N��x4N�pzcdF1[��-J� �9�<l<��%"1!��oYU!\@i���������6��?^����h����D
1�sm��3�	}�>� �����Pk5q��@����
\���j�4UU���US6�>[�=P����j+@��mT�	�>��{C�Gx�p����{�����������+�p��-���}J+j�`^/����(���xP����i����^/>���[[��o�m�����"���2W�.h�w�1J|lgddy�vY����
�34�X��4�����X#��X����:v�B��f��g��ra��qO�1�4��As�A��<9�qa>��,�`RB6)��s7U=����B�:F�Jd���@'������f���'�C���%x����|Vp	N����(�K�E@�WY���u��VwW:��F�f���M��2���>�����C	�wv��]]�
N1�/��x�vhk<�vr�zzZK%����FXwr�3R=&C�������M5�'7W�Z$~5�]���dCG�����*�%)��0g�O��hG��98zv?8Ez$��7^i'���(t��k_��M��?=K��d`�*�}����� ���z���%'�%�@z����6���V4
e���Ggc�����T�$��Vh���$��.J�Mo�P�+�Z�_�^��T�'�&H5����DA�t��:u3i�t/�J$i+v���~� �F9�����.JeS����S6��7�5��5v)��^]fu��TS6OQ~���?)v�hL��u��H��������41B�K��yV�S�����C�r���7��^�����R_�5���������
������k�acZ66wR`T����+@�9����9�3 _.	��N����6��kl����M<�]�0!�g�{J7��&�@�����b�/�-�`�i��:�f�s��m��Q�Q�w���c���6w63�N����0Ck����7k�o�����gh���y�8�]�NZ2'������{pk=k���V#5��["��|h�G��UD�M�es�N��r���tVkeksOF]J-�����Z��r���G��sL���$&��\��(QLB�6�l�:./�T��|��K_�U�j�'��~�������6+sP�=+���L�+��|2�$<&��}��m4�fx�5
�	V���������0Q���u�(	b<�b���������p&�N�PNMW!�.zky�o��D�������.C�wY�;L���7�R�|��vW��G+P��K��rz3��C���.�a��U6�G��yd�do4��[U�8��~�u{F�G�Fa�X�������=zgt1���6�`nf�1�02�u]��q/�<
�|jE��w����H�-�CY����O�[�������E��i�DOG�hEg/T0Ztb�Py��,�A������������j�j���\�ZX��b�9�����pGC�8�d�f}�d��:�����LG�#�3cZd#s��0���,M�	����Jj����2R��6����d�<��0��������k��P��o�6��Fm{���rx^L��5j�s(P,��p��MW����nU�s��	��%��th������O��
�6��.5w���Z��#g0�;��A6j��ah�I������i�qJj8	�F���.�������u��R����p �cp��L����*J�l�cC��_u�@�{�$�[
0m&1�Z$_2���*����(��K���R�y1 b8I��t��_]����Ex�i���<8�1_�,]7om4�UKp��q!Nc���	��"�q-�m����a�`�B����:r���3���Z���,�������G8!��
��
FE��)�WN�����p����E:�$/$>(4�}�c�>R=H����' <�����YW>h��L2aa�i���iu���v ����>6�����W,��!��5����������iI��s�\��]�Q��_�0��Q�?�Z2�����w�v0^�nc���� ������lJ��p����*��<o8nV������ e�����^�������L���@�r��oct}��:�&��Ng���M^P���r]���-s~.��!q/�\cW>���7�����e������Z�{d����FZ��,� ���k��M�U)Ob��N�Th�fhMk-�����N������9�,���_?���m}�OW�H��$����%>FUlR�A��7�TA��u* �l���o����<9������N�{r|����xHh�,��yKk�hFq�������_)B9��6	�����"����h�Z�[>V��� uv����������r`&x�9!��=>9n.��������������*Y/f�F�|��	�do%����3�)�B�)��
�#�i����+�{#�+�[���-�b�|���P"OGB��dCy�u����s���O��� ~j���$������|���w�����ju��SB����!��o�go5o��Z��y9Q<�8�C}����cz3�0_�]]*SY���?�:�E?����6�����S���(c{��h9�!2���{��H3�v��*���/�!z!��`�}:HRm	
��uH����I@��rh��Q ���|�����|/<��]��f�o|(@�Av������H����S�KP�������Td��N�b��>=������{����M��!�������P���������������DHN!���=e�a���m}��9m��5Q' G�0��d��g�D�w���64�NpP������5r�5�������T��U�q�p������"|��T�|0�_��=6��u��u`z��,&u���q�Q��P(n�F����~2;����6Kv������������	S��v�e��<	e:�4������g���e!�V�9(���d7��~��n��+��S������|�C�7M�6��=���R�C����
R
8*�3��":TK}���O�����i�1��Q��[&����������uK��%}������;fF�.��Z^!;�t���F�OR�s)�$�0�}�3���A�p���8�I�eE/����iw@h^�[7�<\���L�?���8CV��EuZ�,HW�����IP��k��E�u�3����r�����d|�����ox���e���O1����ZP��F�T*��i|mM0?���f7���0�:����[�w����pmm{w����^�x���<�%Y��'lc��/�G8���)�(��f|~�����22
3��8�M0|c���7�g���1<G��-����&�cY��K�L��`4��z��j�0���&����wU�;�����M�Z��9�P2G���A�vV1�u*�}!u�=�����w��<�o2�ef��]u8��`��TF�)�aZ����e%�nE&�7��#�r^(5�l���1�\�_��w1oO�=�+6~f��9���=BJn����=�D���~(�OOs�������f8�u>�.�����{���iE�z������p���|��s�y<��
6��[6lU�tZ5S�|@�e+db���tE�6���}4�DQ�#E3��������U��)J_��
~�>M.!?�&�#Z��q�v}������
8YEK��W@���k�YV0�����V��!����l�O������<�]�)`�wz��t��Q�<�hT�F`�� `S-�c�]v�}H�v^��Q^�����~D�=���]+�N����>���*R�X<9�����W�#�|S������������%%m���%�*���"�d�r=�������j,�:]�S��NU>��A70a����l)���B�����VE�t�����_8����<���w����dWx?�M'N�r�/H��?>T����yh���8��������]T���d&H�&���_v����2Y�a= �(�w'q�a@������}�
���)��r���8F����n��m���:�?�b�y�D��G����h�`p��Ul6�5��-n����h��(<�A+*=�}��Tp49p�]|TcK..��-������+V��Pu����q �������I�>���V#u�[A/��YNJ0��l��z�����yh3�� 1#���d5U�Du��j]��.9`��^��M����"�,�!�
_b�D.����x�1=�A5�"�BV��'���F��������o�:B�MbrFpu8�4�*�$�e��������h�l�|�,.%t�h$ub���9bR?��T'�B��oM+o:/����5�/l4���^}�]f��/����z���u�*�k�\�t�V��	-��D�3]��(nf�cZ��o?6>������u��]&A�*��<F��i����.D,
(r���z�e�w�oW�tG�EU���7��������C����CB�T�:�>���H��O�'� �-�����8x�d�����#]_����~\(aD���9L`Yub��%���
��)`B����,N���6�Euj@�!\�������=l����m��|��/���������V����i��/���������O~<v^�0�����V�3�5�[�l��L���b�Qg�_�:�����rN��y�� ��c���A��Qe��}�������=<�z-�"M��)�$/�����:9sN
�p����"����2�E��^�G�t�R��%r6,�C	�
��y�������<����Z�N{-���>+��'D�k�T����� ������5�C������Q�S�b����xM[1���3:L����y������j4'5VR�����N��7'�f{����}h�Kh����Zz0|��B�,� ��<�-�
�LLl?YL-��;2��!���	��U����
��V'����������cok[����%���pC��-���>!\�����A��\�4��zWe�����7���m�|UqQ��,P�,5�a
5�+c�}:�
��L�d����S�A����O+�J��B���+�F�����>�F��y�������#z-��W�]�*B���;�n��i�-�L0��}�[�VI��qw:�����O�M��u����gV)�?�}(=%�D@��b�����:���o�b-�'�����A���.�9#�`��cR���(�o��_�\[���
�id�h��k���������@Ne}2�kjr�
F���J����,��xi^J��[t/+IM'!!X��`q{n���9E���6H�bjn�o�,�H���$o6��*�a���2 ��r���i)����Or#<
����D�?%��=QU�`��.����{��g��	\)�aP�����`@�����"��s�����4�;�;wK9�[�I����J�(���D>�>%6iu9L��e����E�1[����ao���|��v���O���.F���]����N�G���O�~����~D~���,��j\x��W(��}0\���k��-^�������x�o������l�;j�{������-0�V��U��H�����8=)�qX���#S�
1���P����O�����Me�
V�q�Q&2��MXTo����������qT���R����?,d��G��J
���@b�������.d�*9�R����4-���+�\e!\�)_�.������+UO�ji��H��9��N�����P��'����yI
	�-���
��srj��U$�t�Z�]ZX��������E
9���[��osa�F�g����?2Fa�����M�`
�W�
�J�CmRmh��9��P��l�6�-�f���z�M,;���5��l�n��Z���;��_�
���f���M�����������T_G�!vT�!u��.+:t�,n��Q���] ^a>EvUs)yDS��1)�^���C�B8��������uQ�0�� ��_eU `L�&�LO���S�{������1�Ve#�����y���t������h�w{l,�����h��k���������?)tV�A-����h�4��"_v_����/����DXeI�F�c���,����`�)�
��t���?��c����#�\�U:�����z�X��u�rbN���F���Y�;,6�.bw	��D&"��^��Z<6J�f�5��i*]
���[?@{?�@�#XZq�U-!��*5�����d
>v�w-:n�@"�[-/�e��>�K��L�t=��#�9E����(
a�g��<��e|�[5��p����� ��C�QN&{�E�a�8�?���S�����EeC��{�����d;���~5�*�	�J�m��O������N��[��]%��6��������pPU�.[u���)��;_�[��D�C�+�-��L�k[����j��VV��$ �U�h�6��m��Hu��!���F*y?��(�0R�0�w����v�ISVv��-����$���Z7���{�:�����P�0��'��F�a�{�����#�����E���yg��sR���
����7���Q�yU~�N��h��ug��Z��9@��'[NM!,��>![������������V�ZJ1)6X��]`|�
�+��%�S�hD�Ko��p�V]�����"�!k���!6&���3p���?�]M�!W�T1p���8������$���\g�(=&�j�Kg��=��]����.�#�N��o�gM�]n�{M3�ogp�^c����z-���02<�E���A�7
1������"z�6��Pzl��6�1��/R�%�'��C���s5�lnH=�}a�w�����<����f�72c��g�A.��.�@�V
Mm���s����g�g<��	������q�����j��g�c<+th�,)��$8��x���J�'e)1rX}T3�?�rEY]%�jvX�'d�Gu7�Xe���H��eBb{�x�FC��[�D >����O��et�c2�n�,���,��,J~w�����)e�����*Y�Yc7�H�:/���nm����-�������Z���IH
�����C��B/����%��1�u�zw	��yOo��Q�CP�G��/�G��X�R������bY
[\����ke�5��:U,hx��*�c-"C������2�����C��[){�Dg������0��o������]�������N����#�F�c+�#G�bq�����������`���|k�(h�h&+^��Bw�x���*�;�{��X(+�D�'����(�E0V�E$�qF$	U�Lt�6`�jl��"8y�B�������+�g>�5��i�\i�^���
���L�$�p��r��Sf@�����hq��Z���9���M�Q3���j/�z��V�eCX'��G95�)���t����P�-		a�;lw�"�m����@�C��fC������b(��
�c���y���5��DO_@���v�S�N^��w�'�`���������0��d:��,��y�$��<:�&sE/�p��o��%p��w*��=8���V����k:����� �%T��TK�$��(���EC ����m�.-��2���#/�Cx��>J#
<M�>NA|����puz�
�"��@���,*9Yv>s�8]�����:j�k�:kIV$�d�����;��{���������yo���w^�Zf��K>3����������:�=u:���"3A-��x�d��b>�M(D��n�pA3=?WT/-�aP��0�����z��J-f�{ws��|���T�����{�qc]+k�����fo�^n���rW���S��>vP��,��B_�s4�t�8���%���cD:@0����q�S���/�C�u��r�\��h�����g1�z���7�__acZ*t<o}#Agl�E65�����(������gj�)���
��Z8�R.4�b=��&orl���4&\������O?�n#��4(2�oJD��%&E�5�]�
�)T�,p�El�.�,+�|�FyS�~AeE�3v\�%\C��"�9��w�����dO3�Q\��/����jC"��;����G�mw�Z��*����@y���������
�������+3��W>�K���oH�fo�n��f�
��8�2jw��B��8�[���%����O/@�4�/PJ0�QTM�����Vo��P��p�W���o����MaU�y��tR��k��z�� �-�'����o�r�4�!�s��t��7�__�KT�?�����SH�����
�9��
b4+_>� 4H��[�6���H�C�� oxL�a�F����(���W��"�u��*c�X�.0�~6f�K�d��!�/���Ev��aR�i�����}�Z�}�[r_c��!P�_4�r�7���3l���G1�p����kP��#?����=���J�Q��hw��d�a�k��-����4_��	��d�g�A>�k0��W?_�{�F����_����A?.����rYS��mo�a�>����?U���$P<Jh9��9=�0���cz-���cA��m��E��	5��Xe�*��w6����d03/�kT|mD&d|Lx����������^	���f=����f��q7��g-��vS�s��L[���;���^`��[�hR����^kl� #�h6c����&�}�v�7WW�4t��.�hr}3��j�|�+7Qn���]&�R8Q�v��G��p���6�0|}r��iM`<����3Bk�s���/���V �_ >��'�7�4@v�2@���]������RgW�s���!`��GG�������N(G2*C��/��A
V|J�f�R��d�]�q������]����������1�jDX�R���S��px�N�pg�d"�^����DW����B����?�7��PO������WH>IY���O������U`�����Nqw6�e���I����\�������QV��k����|�ll���������2�_|x*<�E�nokw���:=�_����K$��F9	��n��h�z3g����<3�������
��������_(��F����4������X���Z,i
��������"p7�$�o������ ���+�rg[YQ����mb�����F6�uG�$e��4���q��B@"��<i0x������dzv����iR�%8����2�$N2��/���w��|_w�����q�	)��������1�����S<��Og�l��.���@
����U$m}��9\[���;;�~/��*�R�:2T�g��5�l���-P���7n�!D�~����]�&���h=.J1�>,��54�]/���W�3���:`�H���Q����{�W��C������4�F0b0gK���2�"����������9�b�wQ<�dj�,��%Q"C�����!����
%�cLX�a|N�B'���f��������i��U����[��'?���o^����
�F����v��
��3/����������Ql�,V�F�!�|i��+4�<��^&T"����������!�Xn��Hb�6L����$�O�1$���%�D���BrH�B��r�<����J�M��2�����WmC�����L��G�1d�~�������(�l�/��[6�����9�=:��g��.fr~����8�!r�����K��3z;���r����#~���0}#���A�)���M3��0g�L�{�;�Q�i�����a��6�P�wb���gH�u.JZ*�?�<�W�Vtn<C��ZON"p6�o@Q W�k[��S^C��i_�h4�����V �����'���N=���:��s�"zGWs_#n���%H�c#����j�c�e�������j�em(�X��JI�t-�m��i��s�Kg��gKz�h+n�Pa��O��]��[���������y�
�e_kZ�g �8P��q���YF����<=_j�{o��F�,�B����	�q�m dgg	83�C dfg���nO���M���UI���R��6$s�xw����R�T*�UEx����N�^v�����A7���ct����]4��,tn���;�����J�5�C�MI��6$���������D�>���m��x7i&�'�<x�����\����pJm��]�.#�B�����PH�����Y(�3�(�a%��Hu���������)TK��)��/CoIt�7c�b0���3�N��^>�]XK,���w��f��MX��D,�rNC
�7�`��S\� gW8������YS����3!��`���?.�L[1��v�D@U�C���\�"��OF����X2��HG���VTe���'AG�S�T(�T��]�,g�S�C�/�5^UJY'�tj�k�
O��a������U�Q����������1'���sy�0���sy�OZ8:��/LW�oD��h�d��h��%�C�%|IG���j��n+r���"g%��|#
"���5�
/���^��;��9��9/�����G�t:��p��'u��87�/\����>HT�p�(A`!�%�a���p��
X��
	��
���3��X��g�N>u�����)�����]!�O�25���	F�m8(�6i�`��C
��ws}��b�gW��VCqFv3�\r�[�f�v��h
:�~;��v�����m�s��Qo�C�
����B��'m:T�j���`Sv&��{8�i��>x����A����6B�>�jZ�8_��)�]�T't�H��!C�!������!��~j�[rI��
����"h��5�����#	������z�+I��^�d�����4��� Z"�=��L9(�(@�������Gw��%��d�.Ecj�����H�F%�p�I�\!��I��DB�ySK=H�O4�c������;?u�����V����4
���a�y��6�^��x�jn5�������6E>NM'
��Y��.�!��E'���Wt���)~��6
{�4m<�����x������l�h�%�$t��&����FW��'�&k��i�^��$i�l��u%����'���1������>]A����v���^������U�
W}������}��AQ��lUW3v��,E�V)�Gxp#5<����=������}yiLg�h�II%���[��RM��L���e��f���$Rq�n����������E~8�y�z���XS�K�
?J��`L�S���-������-��5�f���<������
q�N��.-���|n��?�//�]�RG���~c~C���^0�(�l�%�b�o��'���>5�_�����:$��D�~c3�a���n��g�}��p�*-{m���T�V��y��'�����7�]��z3�;��HG.��\��wA�V�����X�^�����7���	Emo?r7cq�?��v��H�#a�_���mq�����o�!�'�v��Q�z���Y����Vw�6�l����s01�w;�B���l�R��|\D��z��
�S��J*��b�K�:��z��+�����=�a�sG��G3����w��l^��M�Q�C�*x���Z�����Y{�Y�H����q����7I�7��pk�|� ��M0�������9(;N�k&B7�tr^��XatH�
Az~��`'x���U���81E!U�P�f�~<�8����P����1���q����ON�R����(rz����L������t�\��L���������)�P��PVW6M��i��%�t)f�v��-�e
�*�O>��/����)<)Aj�d�����/�w'W��������AL�G�5a��� ,(q��u�VW)�����Jl����`8�i������VQq��3��$����Bp�R�\��&���*�&�T�Q��+��s<_��aT^C�e);�36�8��	�>�x,�t����Gx�~)��4\gq�",�cU4��)�"��n/�Xi�l^�si;2�����'.��*��N�x�
.�ZL�y���������B�w%(]����u\'�1������A/��`1S�Hv.����*���}V��v��{���(�eW��I�>�`�5�d��h4{SG:og�c���X*�-��tv�H�������= ��%����U
"����N������R�LZ�l��}�31������Y�\�����~�s�Z�0E���6�JI�4�����0���1v����:�6Z]i�
	%/5V��a�G�0f�����L����8�TI��1E�X:��4�R��ta�%-o�\	������y���^m�QE��/%b�h�a�d	��ekg��2�`i�u�����`��\�x��8�H~�WWta�u��#-Pd���c����*��"���h�������F���E��5($8��	�O�>Q}�p<��&���k%r/���b|�{Xb�Dx���mV���@0�l����?����s�4E\��p/G)�;�b�������X
/w/��k���;�x�{�{�g��N���%�-���-�a:l�boO_m�����������pD����zE^b)xv8f���dk`
?i"�'���H^��<Q�3������M�^�Z�g��H������.52`��y	�:���f�%���j��9�J2y��q����c������}����*���2�Ft���?�il=�v�l�@��V=���.o���\��	S��Q0TFw
[����F�� ����H���aa����y�M>=�C:��j����������_-���j�d�O6����o��z���i����x����t>l�p��8<:���^r���!���Hz{�&��P���@S�
c�8a�X-�&IT���8#sK�1I���g�h|IOD9k6�����S	�BfiKO~F#i\����U���Q/�%��	�Z>����
�T��S�=	�:�R[2_x2{�5����*>O�m�7L���E�U_��P�I����>+�+`��W�����u���U+<���hT�zu-�����dMG3[�Z,�����|�����}j���g�[>����|UiT��\}f��I��B���g;y���S�#��r�]5���(OX���_�+��eW��J����M�3�z��0IP�������V�������Z���&��2�9�$����yy�=<c�}�=��I�wF��<��� '����j���;
�jL������g�e���Q
w���u������r�~������df�V�bl�i������iP�/�7(�X%
 	z���t��`:u�K�>Q�#��"1R��9`}�#�]�eB�L���`s�e�2~A��U���*GBB���3�-N�h�*~����g�SR�D�!M�G�zgpJ�&{l���K�e#I�� y��>���sr�������{�p����B��L~v��l��&��$��O��.E����W�F��']������lz������/��Y��9�F&"G����8�eR�m
Si|f������}6��TxMmN��aN���9Y�z���d���re;��}L�q�}*��r����iue�ZW���]�che������"����P���{�Q�#����W�"p�����B_��9��������E�[���I� .M*�UcK5���X������6=�mG��/�qe0��j���.?��v�C�}�����(�����������R��eB(C�u�PpJ�	��b��������C�C�/,�ZAo����h�;[�NgF=��%{|��`o��[�
��`�,�� jy��a0��GA�"������G~9:��U�p2�U�tQst|z��N,�������(T'/w��;/�T���A#buX��p����,b����v](Pa�zT�����I�� JXv�k�G|����<k����q��=zM�$1�6U�	���^yB#2(��Xi8������������c����	.����������Ph}|���d#�4U���
;,`�^����x���2��-!s��[�������r�-!D^{��yd���-]����p�b��������?�\C����5!>+������l�Qw����!8�AE<r(M�8`�����)�k���Xy��k6l)��_��������K�����o_���h3@e���-�������7���?�i��s�Y#��E�X�_��7�&~��(Cm���o>�j�]N>��utpp�Ky _�����E��nY�A��������pXj�1��U~�S�����`�g��9.+��i��
?�v��u�K4�+�����}������Y<�����9h������l�`��a<�9l�>��_�O�P����1#�b����0w������|�v>���f���C��=wEYs���v	�q='�Y�1SyXxw�"o,���^� l�|(��A(q�Z.Ov9�x�Fk�c�r��}t�-9M�N8�Xvq�.Z�J�_��V?����eg�l�b����"��[�_����N�����;z��$!�^�X��n�|�����G�{eY?�ut�0=)�=a�����7T�G�����1.��aIU�5��B���M��}��p��V����#����I/����#���h����B,�
�r\1���l}��-f�7t���e����Mn0��S%*��������t����(�=�����h��yP�MQ6�([�-���#@:���^+f�J3�Wo�o��+>D���{��s�
��F�����(��r��EW����zg��qR�,���t�F��������]�|�3���Yr��<�;z[V�T%�	��j�����54T/��f�6��/�fg`�>�K�	�5���r:N���;y������9t@JC���k�v}9�;��h�qe�q��t�n����s����	��x{�����^i����p�y�uM�#of��J��$��=�w��f�����~)���`���p��zL�7����fNJ��k������A�o6=�l���~Xb�=/1b�@l��B��p0��X~���d�xA�i�pe�W�D����{;���4o���~�����j���Yz[�
�<*��z1��&�i
/����f0���.�.fd���'\Z������S�sGs%�������&m�1� �]@,:��KD1�xvu����������xif�W3�"�K�����.������g�����	�I���e�V�Q��JN����_���(.J�(I�H8nU ���hD���2X�������5o�7���M�hp6���(�T�����?-�^�TFCZ�8�n��������I<����C�uM	�����N��7���GO������quFY;{M�&���g��x�,��<:J��;'�1�f��1�B#]�����R+�.0�5R�Z{6���@8(ipL�W��.x��7�&� ��?9�y��nL=���.?�����h4 5�>��N�r5�=KT�)���>k{��n���vN�����*����a���R��>����)i�����]q�n����t���v��4x(�>b�]�2��3h�
73P�j'(������:�%����K^E����L���\	�#qP L���x�?� 8��d_��������j�U�����!�����g�D�&��+��X�t<�����G��q2}O�}�H|t-l��Ga�2�������e,����`����	
;����ja�}n]8�%��*]����?�� �W�����_.9���8;cp"���|���sf�0u�57�Q8��j4����5�����*��y$�I�g������,H_���X$���X�i3�
�q�����	��\�v����dtr.����'����=6���l?����[TM��{���5}���l�Yt�������Z%����	.�#���G����8��n��q�o�N�`�C����&R��ldn�;���2��\t9�D���L�r����6�;@I��Z�����-ut�^`��d�C��z��R/��	Y+�e�L0[	)&a*�c)�t1B�V��7+���(��;ZC��B����F����Gb�cR{��T�IS���L�Kx/�H0��nSj��/k��F	�H	��;���js��l��g}KK�m�J��@�nN>,<q+;�]�|��DNJ+"�I"��	����p��v��`����Oy�
S �I@��@-=�F�y�/8�M��5�l;)Q��B��9��g��H�_�X��L;:��mX�����WLu��h"��z��h��Y$���`$�@����H
O'����m\j��3���f���^�+��Q4.�?\
���c������}���Z����A5 �%����D��1��x��C���Y���?
z3&������"Se/B^D$�|B��:3N��!m����dS�*���KJ{b��eu&�x���T�	DZ��G��2['��#�1~�Q0�]U�n|�����9a�uNX��	V:�K����	�;�a�.g�Sn����	���qY�d(l"�����q�b������f/hou�{�f��<z��[�V��*'o�"��iw���,�����d�w�t��4�#� �M�v���:w�y���<��+��<�0�`�G�7S��������QL�=��p�l����Z��o1����*�o0���{.!Mch�@"D��]�����o�u��>�������o��t96v�Q�|�^�pJ�U�1�����e@l�CE��aw�������l���:O%��85lT'
�J�A���B���|5����O���)�����Y����2P}	��\I_��d|��o��%XXh�:y]M��"�������#k-�X�a�\�lm�[M?�l�����ol�z�_x|$��S!��@��
��������w��$�n������P�]�K]�)5��^F��>���B>���6;��Pb�������K��+���}��!cW���d�
''0�A*�@�D�jg��	`U�#<��M��!�9w������#�"9m������V	)����5�G�������Eb)��D���x�V[�1P��1{������������1�&��C8J_���8��n_�����U���]�g�$�T:�g��-w�E�1�a,jt�E�����^�B�~�5y�^�l�����d���$^B��N�|-�4�D�FU���/����q$��H=�� v"�����,NA < �����*k�\'$�XUBw����yb��������p��~��+��+O)��@�:�L����LyQ�l�e�*!���!��������1�
3���[����� ����N�<!��-h��5J� �Q]��/�����%{���%�N~1>�E���t����F�E[t�k���\8y�+(��3������tuG�
��h%n���H�*�������N���w'��dV�c����)3a����I�\�a��
}"r/���!��m�[���[b��)���fy{�h�����`y�G����owN���w4�\GO=v�b������������7�Q����!P�9v4���j���^`.���H���]c����!�-z6�N~�����J�Ov�Oh��T���xN��=��<�nRX2{:Oz7S�y�_I"e^����������������M�*�X.R/x'g-��Dm�kCM.�����	������1D"��w$�dx�>�Ua^��9�f���`�$��{Gjp<�H[��OR����F=A���Q�6#�3:?�F�������J�������#������[��q�:=�EB��nA��*0���lylH<�G��F���!�X������V�(<����I�|U��<����O�N���t�)���w��]��;U����
��A�|��v��M��#��?)���F%��)q�]x���lv����J9���F�pZ<?��2������R\������l=��j4�Q�y��7������0�N�y�E�������q4��������F���C�\D��M'�-�[BY!5�L'Wa�B���+jt�~��j3�V�g�Z�u�(S��O��m��I��|r�v�z�|��0[Y��)���������`4�l|	*zp����q�������������{�z���~�hJ{%�P#S�BK�NF7Wc���"���M<z}F.�3�����6�i���W������a����Y�
EC�h�W:.=c�1�xQV��>4� -����������t_X\�%����
(���K�Q�ER���ps�������0���L��{X���W������A��D��
�t7c[v����ijU0,<:����s5�HO���,\>Hs�&�dFo�2`�_���`Z�V���4��W(Nk��^
naT��j��j�B�z�x�/�wV�W����@M�����*�O"fB�w��T^�$�~����>]\r8I��
���������]�b\i�>�������urC����f��Hj/����]�x7^��;S�:�����Uc)��x�P��S�J�]���M��J}SA�WAe�'Jm�����
�A'�7�pk�����u����l����tOy���\��� 0�d�zv^u�8+)��ia�V�����-�lzt�@��^������L�r�<0h��W����B�zKfq�s�
.��1>���V�5UR\g��s�n]n�x�.��;��C����36l������~�n�Mll��AQv�5��s���K�p�x%�\���
��<%���?���_nW��#r�����o�9�HW�Kk;���%� #��i"u������F.9�+9*w���X���y;y"'�([�6�!F,�5�5�������+"��y^������3o�fo����E��iPYd�EZ&�����&Z�M�h�(.�G�	t�l�
����d��d�Q3���%F*����s/8��.�KB�&���J5x����U�j�+�!����g�z���Y-	�mL[��7D0&)���Vk�����[�D��%Aj'k�o���=���^A"X��l��GUl�-�Y	�b
����xX������z3��0J��K1��07�����_
K�9���� ��JwO����]tx���O�1:-������.F"��
�������C�Z���E[�-+���k����W}���wA��,D�U�>�B�A���X���U��;Q}���$:#K�(�bZ�
d�9���������<w���s�l,��vH�oz��M�of������a�}��z�[P��[c1��kVL���w�'n�1�O��hem���s�%{G�w�	?��7��jp��u�i�^8<:E�/�L��)��T�N�yr:�5}�R�]�Y�M&���D	yD���>-�����-�H�%i�R`$~7�ADP|���G���b^h�2���o�/�I��l��$m�6=�QW>z!�U|�XuW�X�D���QY�d1a����D]���9��-�<���"h�~	!�Q�b�o
��H��*�}�^�Dr.����3��������U�%I��%m��WQUHEB�lC��������K;��-MH������`��W���
���xx)���Q#dZ�^o���(�C��}�KF����E��J�V� ~�~��C����f����}K>�;n��	9�i�>���K��C
4�M�����U��TI����U<^
�NK��%7���J���s!V9��OS�����]���	��8�V�V�+�-\�y���[��<�nbf�z"/���s?��)-�*
��$�Gh�����<����`Z��p���e����&=zs�-��v�R��M�p���n6�������d|-f�8����c������x����q^19�Sy%�
A��N�����S�^;��J�:���V��F+��G������ssY��/�����?�����7�L(��W�G1�&��\2QO�%��d�Dk2mn������3H=/NL�������� 5>��&���L�1�R3���i����s��g�z^�(%S��L&�sNTSm�+��I���+�g��sK2UT��g���jc��B�����z��!������G��F���Go}G@y�.���9�����C/Ur�bcCPR0d��(��O&��o!�NZ�R����J�M��V4�QBXG'�?�����r��Q����EiyMj�|vN����py!��������CO�3�3�yn�B���jI^T��U����H�AiXR��t�yn�Q*��&	3�J�;b�H�<T��c�]���-}$ >�k��.����|��"@�8��(�]Y��������z�+�a,�6V���q�����k���NF���f���^��S���B�p4'W~�����:�C�w��!m2���1��N
?���F��n���0NX�A0�4��K�aFF�+�Y!��}�s��<g��5
��w���<W4��qE����bX�<"�h+!o!&-�S�7���TJ�R8��������<G�I��R�;��6����1�����|�@KCT�>;�vFpV�)��xD���;�O�s`R.<@�$'��P^��#�5mT����%O��I������W'�������/���rwAZ�����u�c$�rn�W�D��w�p��j�����"��CY�7�<���Yn�%h�w���R�����
���y$��c�y��9m�,���x�UGT`�-����mQ�=r�j��"(����~\�w�����f�����i����]>�O.���~��7�C�����A]��@�p��������+�@J�Uo�;uv���R����R�#���(�^	��������g2��o���W���1�������0�B�����7	�?�������/NEDBK>&�im)�Rr��%&`=����`=3X_���B��/)����%k��Z����Z�P�2���-Ci(�5�����cP0��e�&�>��LCj&�� �N�����`���g�:1y���zv��,@h�ENf��cZ=��&�
�>�l�\��c8�GM���!-DR�Z��}��3����sB&��y�}�@����������V�+H4���]�W>UhcDk���J�x[�)�AOn��(��jY�~�\.d������x��+�s��:����
�V��7F�k�����$C"fExI�^Ovh;! H��|u:����,�}�ix�|_���2�q��9�q�����n ��N>k�z������ZP9����v����M�b5��.pI����/Nw�J�z��\Yb2Y��.!���H�-�)�vy�)����L�������N},!�yx�k_%�����y�;�������7M?s�z�m(�P��o��B���I�$F��R�����Ow^tS����T��2�j(�� n+�w����$�3W��R�8���w�O��=X������	�������CM_��d%��$_
�����w$P'��m���.�5�B;'A�W]�h�d��	��gp��J>&�U��e��&�E�i�������S���o$��&�ZDI�����������2|�S�@�+��6$F~��v������xc[����2���@
<5D�c
��#\>��J������_��Y��S��%�1v��;��[�V|g�Y��*�X�J�l�^2�.O��.xF�u�6���YSV�IO�+�I�z�v����1�^^�G�LE�)h��4#�4�0E?rBR-�E
4����J�I-iTI}YJe2e����)M(��7��5f�j�����c��3���B!J4��+�z31��;��p
�+��x0�^�F��i�U���d�������4x.0l���O]R5���U��M�G�rNsn�,K�d�=��'<�������D1�`:���<��Xr�~f���~	3I��3��b]��P{t�1�jzA�.���0��p8��s���U��B���
�<�|g�1m�4��c+���D�v��e�
n���{|J�
{d[��wcT���S��D^��Lg6�Y���a8�E��)7I�Z��v��`8�}@G��h����nc�j�\[��m�_�o����W�����'�m�j�����u� l�����m-���i��#������%�[���v��������7��p/����YR��;2��a(b�����j��?�
��������`�7������"���.\���kmuQZ����r�J����������y�]����"\��Q���~�����������}r��+_�2m�T/k�����~���Gx���56��������[9p�Q�������H-G
�X��s�|�HEJaF[*GP�~��2Lb����dUl��M����\��|��8�`�7)a����e����V�s�+�fc-���5���zzcZ�0��Z������V�n4�����f{�D��uj0�c/������^���o�5��5	M�;;���r0����u�����{/��=���5r�io���u�z:	��x�������TI���*�rtLX
�2��t�Q�-@��(�>F�x��1�`J�l����)�1���v\� 
��D����;\_�'9��-��n��F��iD�������woD���m�tD�t�g�E���Q��B��2��0��:t\cT�����}����f��������/����*7Lj�F���_8	f� 
���Z1�W������1�Yr�*���yiF�i�{RU|�wO���T������� ����=��oO_me��%��<���W��C���`�2Xx+S��!�a��?y
��6��0"Y��������f�D�Q�s��w%���������J(k�G���tH�Q����bg~����������d<��1���_�D/ez�$��Q\0����
��A�y
i&�q����,-UL��|����f�s���'�W�7��a,t,�y����N��+�������7���s����I�Nv�NNO���W��4@D>�#�#]Z�0������Q|3�!�#�q�-���M��[�D���z�5�I����wmG���v��Z~�L���Zb��e��|XW�V,$�Z��e�P,�x�!C����+���Y��o�
��T&2dw^��q:�@�Ks����EE�s��OA�)��Mv]C'�(����r2��l��w���]`��Sx3��b�;V���Q��Q��H�2HM�`4�ld�m��1��V����F}S's���(�#Ed�kF�\�H��H�s0��~^�����#Gv�cD���]��cZ�sv�d0x6�Xb_!�����������mogB�/��:�bE��(v�����U9�U�^��4Re����M~<��n�o����� Mo��o7[�XN��`���*	�l1-�����|&�������s�J�q�3E�����NF1�|�p$c����n�w1���{A�)�����gy�f��+��*gG95�p���2�O5&�/
���h�G�Zc�UF�qR����f���;���f�4c!�Vc�����mRU3n�����A99��so�z����0Z�e8R,�;h����2`���fW���:jpDHM<��}��
�������8��
S���e+s�f7��v�k�<����=�y��:���5��Fp�eVe�Bum*R�q��K-8�����4�������z^����?q��+�{�>�ia����(���b]��|YJ�����-�?������ ��f�./�tv�����.DJ����7�f�%Eea�K����P;)����Lgz9
b���W��8��K�� m�c�P�Z������PL&�m��9�b�|�.��`CU���s%�;,*�c]K-MK�xDm7����d��Y��wxX$�`�Z�u��"���g�B�e�#��������8�������4~Q��#�|�*G��p�'Y�qA��HG"��F�U	���9����Q�������UD��'��0"������k��l��c
3��(�������v,:�]T�K�A�������X��������$��!S���*'b��&
�2�\^���=��y�;��W�����]z<Eb(��\�T'*<��~	?�qVt����
��e�VF�J���1���>"y�<3eg�u��<��Ioru=����N��bD#|���m�GAP}(T+kOP�����z
��������&^��?�{���T�<�b��-�C<�'�U��4O?�f����Z+�%E�X�n���.6��l�'!X+�i��%J�����#������1.�!tt�i� ��D	��������'������<�g�ai��\����C(v��~�4���`@�{���\+�W���\��ib�T����a)�R%�����m�y�}D�|������i��$��A#�HZJ�'&�2��v �^7w�C_K��
O��
?=O��/����G�"�Db0ZA��;1�i��� Q����NFW�I��P��@������i�l�����H���2)M���U�R��*������@ w��D�p�6����
{ �~*3*
[�cl�C������E�YD�����s[��g�c�t.g�qks���q�U��v��A��Z�Iy
����vl����5��/`m���~��'&�bQ�2q�r�u3����g>�\�p��Zu�h9���G�YP�}ic��g��>���v���{�8'�h)�X��6�c�[�*AYT����}�^���.�E��\���:�x`{Hr��:���>��8�0<'��;�i����$�����0�xxZ��$l�:	��	IS�TuX!������/��Y��0�|
V�b6,�r'!����aXO���L�|��T�i��L�o1J���
q�E�3>=��j��C�:�������o���~��/B����0e���0)��LJd�������������4����Y���p����I��p4����Uj3Nj��b1c��='��f��9 �BD���L��[�����,w
1<&�d
�{F������]L��8u��\[�>f3��/���QgZZ��q�)�����1y�+�����%�����QY�x�e;yv�x��BB3�m2���2��t@�5������]���Ou@u��:�P�|��(�M;?���8=Q�����0���j��"
�`��8���}E1�\%C �{�������,�k�(H6�>��A�f�v"�Nd�)�����j)}j�P"�1��<�h�R��
��Tm�����
0�O9� -$�s!�_N���DFY�H�G�Z������"=�*Q�_�j����/6��]�a441f�IV��V^���Z�Y��i��&��������G��4okO�l\���n�\T��������/���nR^��
�)r0��a�����v)�9���E��y���V7U��4�j�������@����Y\3;��!1�����y(�v�5S[3O�d�Y�1�Q��*������z]?�:SH�#p���K�})����s~����b��u���|)LS�tYw�2-�R�S���6�����4��$��%}���Z1�gG��K��z�@������������p��P+QRn6��}Rb����y_�����?	��q��>:�o�s��iy��*����O�;�������o��_�����Y���;��@������)9���������7]��%f������HnkKX�c�n2l2�[���?}�g~v�����V&���dkI�j�R�<��(��z�Q}���T��z�P�;��W;'��o���1���Q�`d@<�P�q�B����U���p��7���39�e�%�)EL�-[����V2Qn�4L�,��s\Q*�]������������::*m���������S��k�~E�Ea���,��o����t���V��������t�T�c�U��{�X�:I������-�E��)�D,3�9��\T����SV��S|��}�e
y�x��+_��:���q&U���Y�^�K�&�sC�����A�}M�������?/AMe�+�����J ;����e�;���m�r�a��3$W�?6��<���L*�G��4���y~V�^�>�����Bg0��0�#7����e�}���@�G���l��}������p��+�6��~�y�\|F���r�[�!�$!���������\��T�F����7�'-N���IE�G5����3s^h��k����__���;�l���%�9��P+d.Cg�����,`%8��R
�I�4���c�����JK�J�DA/������y�j�j
)j~���)[ C�w��_�-�J}�h������������itIYeS�l�M{�u.�a5�1vc�������}5��H���	yu3����19�p�R��u/J+� �%�v��h�|��������g���P��{�^�DM9��p��|�2����z�{0/k��RQ>�Lg	M
�a�����4dX�����`���"�#f�����<s�M�-'�,a�)�2Xt����&i4u
�CSu��V����K��b�v-���������-;r_`�_�f��j1zO���.,�G�Y}9��S��B�%E6y�6oW��i��iru�\j��6)�rN�T<U�i[f���7K+M1N�5�mu�
�9^�:���?��jI:��-��&��goFtPz����4K�_��T��IU�*O��V��>{4�@�?�s�h����k����WBB����$�N�����W�b1�k����F��aa�����
xpo&�`�rf��C��2�j���k������\6��O����F}<�H:
��V����7CL�A�������y0�(�J{!L�/"���q���B��tk��B��DkH���f�j �;��b$����{��J��T��Oe�4)�d����<��Y.�]c���{��F�?<������#�(����#]W�_)����R�����g����y��u2w�<
5�o��:���1ey�P�L�&� �}���yq��Y7UB���~��%����9:J.�����D\*�K%MC����V�����M��������A��7=�E��|�U/�y��}���h��-/
'�md�����9A�Y�%�bL���A�����v���Y����f���Z+�lJ(���l����\*Y$�A� �63��_��J
x�)C�,�60��I��J'	���
R@+�������:HQ��/���d�iR���|�/&�$)rOX���1��I	� )�,W�����b��|�a������s�_)�,�H�y��7��D{:��"~$ld(K5�i��f������o&����f=�H�f=�H�f=�H�f=���z$_��������7���:�����]�M�&T��S���ov��������|�S��|�SL�|�S4�����v�73��&J��.�i�k�I�&K���_�������0��]�������2&D��G ���	H�h��^�����pj���?,t�Wx�XLHe��{�dV��j0��@�qw\���L�F����^��&9���'i�O�U���g9(�_�[/[���88�,��p��*�WZ>�o��5$O����V���L��MV��-���Ba���b���1��[��
x�Pk�oYs0s��O4������k��&���z�������3��0��q���z[�+���P��'�UF+�*Cn����p0 ����	����3X<�F��(��Q�Ie*]��wQ�f�����p��nI�|������f�y������k67��:�0�����a��?�����o�5��&@�mG#�H$&�3��>� ����p�����h
�ED�����M����Up=��IorNV��I��_;����w9��\����wL08�F#�1�U��:��`lm�]��j�_���]�E�
/D���� �������#�VHi6�l�/eZ.c*J[�����h4�~�:[Q�@�tP	���|mn�7�|�?�S�RX�"%b�h���=)x-u��!M��x=
����,F���,���������g2��k������*���v�����`��L>�F{�j��F���Y?��������	tI���R�&�?��z?��k�Zv�1��b�����������g�W�D��hP��1�Z��G����bp4������u(���4{!eS��PtF�������-���
}��.��N�Y���������h��^�,	�p<��	��L`[B�����;����2e}6!'�<x�
�osV�8z(S���m�c^�P:�b�R,-%��V�z������z�Vd��7�u�������-
��h��U����2�l+m��>44�~����$�1��f�kb������"��C��sUf�S2�N��u���#�F���w5���T��.RyV�r��F)���o�4�u��\��p3��������������Y���
^��H��bR�PJr�S�xv���������C9��b����g�!����	������hx����1�:���w^�=6������{72?���8���Z.]�`����\5���k���|J�'�������V����(l���C���-"���%� #��`72������`@����q<���I8���`L��A7���XH �������E
W�#Uu�QpG������G\h�Ig�|�Tl�N��k-�x�^�c5���Y�G}k$=Y
����6���z�$��N�b�N���N������S�COJi��5B��ek
az���S�E�����<}V�jR	v0
�67,���T�Z�L���UDG�<U��F���Q��>�\�@w��{Lk��yk�����9�e��c���{)0���*��?��<<([��@���v����Ay�!�j���~��\o��~3��"��\�x�7k{�����$Q��Y�c��\�l���q���k�]���%�b<���-%jdA��<���*a�K���+<W(�w��p�)�6;�m�k,TF��(�(Tr��-����W��uk��t:�VK@����
_�9�u)����c)���\�KDY� 0��
��`��B�d^�g����y)q�j&���-9���T�Y'N*=k��
��������6���C�E�2����r�"
� (Y���W���B�W��5�`B�[��R�w=�T1~�OVq�$p[IA������\=^�?����r�p���>���-��8%@�V������V{�w�H�,vk���e[>���(a��d\a�������i�RM�,*����_�w����#�G�{�a{�����C��<�RO-�Gz���a=��V�#qk?�1/~��u��<I������UT7���'�NT�2��7��:�UL
�gz+��Q�V��1	�������z,x3.�����^�Wi��A�I?�������O�r�7t�_'�s)-������&)gX�"D�B�}
�j��n�
�������@������1-1/������%���,H���@��,b��y>xT�<7����)��J���,�3h��`���w��
6>��na��:�`8�!��%,��v�����j�
�l���F�<�oz�(�;C������!h-���Z���$�_Y�9�b+�9�1�?/Nv�|me�\-Y�U"j��U�
��p��O��Y�8,��s��f(���6XJ���j���E{����)`N�-s�z�.4^���h�kf�V\�����G�������q��j�P����(� K���/�Tv�����6�A�Uo�;u�~��T���.�j��5������M �fW@�i��5�h��6���7��Yw� ���K�Qo2����"��cQC��7�����kl�����q�����zv\�~��Y���VW\���+����[d��cX�I��!-��Y�Z��}����M�.d�$1|�����Q<���t~�dX�/�����2M�m@�����3�@!a�A��#�,=���:��;;W����d�i��/ (�������|��db�J���|v������R�m?XS��cR����������������]�~�R��1�l����������,��$K![XI�H�9�A�K�Q	���'9a�������,trz��xjF�����cw�'|�!^~;����HVr�M����N>�d�t�m�:����O�hP�����1�^u!���!6�5*��Z�#�D�������]�i�������n=���7��w��2Q�q�$s7J�v2��)3�����D��[q�h�Ab�st��N��v�@�N6���+���,
��r!���D2&��n��[����K���4�b\E�`��.����*[8�����n��~8��T��F�a�Mg�@0�M���;����;����=�.iS�1e�=e���V��������S���<��".���N������fR�;$����dqu3��h8�#�>�Psd��^���CT�����J����^�_0X�54}�������^\S����(-l��7"�\P	���������}r��+KG%�~l���������������e��������m	�QhAjv�����z�(X��T�	l���Au��w�)�aK�7!�f��7������z���-�b������	��������<���]^O��q0����
�������V���z�F#h���^��=wp��A�y5���'���V}����	.1���./�	Z��
��s���zO�K���w� ���a8�j����$�^�f��w^'�������� �@e�r�C��(|��XG�g#j���o��C���]��4��7�:	of�E��aL�����nO>r8R["�t6�V�-C#��I�{�F�m�����=Ae�����$��9dJ�h0&������`.��KM��p�()C�KG������\nz��������y������r���q�i[Q,���&;� �����sj�S�tw��@�A@��zI����#A�&���!���Z������?C����d��Y��ZyjhHw��s�,?���,U4����<�D�A�_����H����_
���l���a��l����#t\v{!a�HE
�uz���j�}��d�����p������v�r��]��&�$��1�05�Y����sEo�i�;���������Z��(��U	���'��Zn�.��Z�� iz�M���+�+Q
�����2�r�M�z�j����o�1m�.IQ-��m�b`��At��w������4C��$���\��i.�k_������c6l97�T����������]JU�i�r7]Z�������yc�<N[<�9�*�t��X�4T��Y����?�^��	���7��J��}�8O}ocA-?{���&��6I�
�f�Uqj��Q�s����eh�W��5������"�n���<�RRj}�P������������Y��<+ZQ����O/l�	��P����_r�z,�"�1�!88+Z^���g(k(�b��e��������
�Y�M����+kO�������8�����}��xuX�?�����yn�.ioq�G���W�U����D�����Q�]A�����D���x����c�%Yx�
��L��y<��U��(��7a�$O��#�����-�������DP�-�
*�~�������'���P}��I��T`Q^��MBi�����*�9�
U�/�lWwzl�YH?���Ra�4���y9�(��]Q����s�nU1��$tP�UKw�h�IP_��������L�B3����X�T�c*S��i�^�h��C2��������:�\��2�\}�*�A����&xfy����|�0����Q#�h�K�4��:7��>-+_��F��e�����uX�ru�i+�9.������x:bPd��M3jp�g���T�����a�[OO��5q{���x>��������y��B�P��pv�����p_����O�z[��B�L��.���r��������d�~���x�{L^�J���vO
]H�d�no��O�j�����;}~�V������y������������a�(���"
6Y,F+:'4v�<�!��H��'��C�;9�8p^(R�a��,l��hd����q��!�G�������\�>O ��4�p&�f0�Ki��K!G���q�J��9��n:�i����)�YcwN���S�Q\3;���t�c�n�j[���L�mM�����:�
��r�3$��9>����
��]"�"������To�Q}��������rT1�b�lc���-^]���F���������z&��{Z�a�T)b�lQ �Y%���~�|0a�t�@�
���V�:Psp:W*PSY���]�&vO�������S���7D���$t~9[7_���I;���ms�#6~i$�w�
i9���"��������L�*d��?L�����*���������h���F"�c���_��t�n���"3gJN��4� �����E��O.�j�K�dw����jW��!�b�m�y�j����%�G�e���y���1Wa�L� ,�lnK��"X&����P�L��ao�/�UUm���o��Z|����E4�{�f�����yJi4h����:?(���GxM��ho&t�8���TxA���W����}.K&eY���Z2�F\��dV��T���m���ga�0�����QL�'���C��::�
^�HE�J|����'y�8'��O�I\�����#�2��L����&���?1#�����f�T	o��������	�z@�.���Q���
�RI���a��Q���52��oz6��!�}�0��������C>��0�#5�T%[^N����}c^I�	,<B1=�c6�I����~�������:r�[�,oB�obQ!KK�0���V�m>Q2��]������s	���`Li1���^d�F8`�@xC����(�V,b;<i��j���	��j��rCT{P�y�B{z�o��F{e���E	�wQ
0002-JSON_TABLE-v48.patch.gzapplication/gzip; name=0002-JSON_TABLE-v48.patch.gzDownload
0003-JSON_TABLE-PLAN-DEFAULT-clause-v48.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v48.patch.gzDownload
0004-JSON_TABLE-PLAN-clause-v48.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v48.patch.gzDownload
#52Andrew Dunstan
andrew.dunstan@2ndquadrant.com
In reply to: Andrew Dunstan (#51)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 5/8/21 2:23 PM, Andrew Dunstan wrote:

On 4/12/21 11:34 AM, Erik Rijkers wrote:

On 2021.03.27. 02:12 Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:
Attached 47th version of the patches.

We're past feature freeze for 14 and alas, JSON_TABLE has not made it.

I have tested quite a bit with it and because I didn't find any trouble with functionality or speed, I wanted to at least mention that here once.

I looked at v47, these files

[0001-SQL-JSON-functions-v47.patch]
[0002-JSON_TABLE-v47.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v47.patch]
[0004-JSON_TABLE-PLAN-clause-v47.patch]
[manual_addition_fixed.patch] # for this see [1], [2]

(v47 doesn't apply anymore, as cfbot shows, but instances can still be built on top of 6131ffc43ff from 30 march 2021)

I hope it will fare better next round, version 15.

Me too. Here's a set that should remove the bitrot.

Rebased for removal of serial schedule

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-v49.patch.gzapplication/gzip; name=0001-SQL-JSON-functions-v49.patch.gzDownload
���`0001-SQL-JSON-functions-v49.patch�=ks�����+0���>����RU�:���4O�i���z(�YS�JRq�&���.|�a'i{�s� v�X�.�R��?e{�17l{l����0�����81��!7v���
z���=v�g��g�����z��Q;4Cv���eO�^��t��
���������3�CvnFMv�^�@�3��v��.ku�n�|>��[����������~c�o�w�{��%��=+r|/����)�nY�9yXK�[������sF������$����`�a��&~�~a�h1���o���[j�V��l����w5u;0���j�wV����l'��U@!0l��d?<7|q�v�{]c������=������g}a��u�=��?pk��/'fA�����;�%����3
 �{{L����D�}?����g�&vd��|��������%�A���C
P���tK`�wH�E�S��Wjts�p��i�rm�@�yT6"
90X1`�M������?����':33��Q���$j��#�@(�>0���rf ��������	��=%��Bh�si�����,�;(U���N��}��U�EdW<� ����UC��Up�^�vL;��A���%������ep��]�Y4���h���D�v�{�`]���b������$y��yr{�%��=	`w	 �}�\���y����D+�V��n�j����t�'v�'�/�:����[%�"���h��
g�U����\.���������t���b���9���m��}�t����������P5m3�,d�n�V$��i��v]w`T���B8��3�d��:��L��"��/�b82%�(�����lP���JKus�:aTHk�

���M��QN���)f�o�n\���~9\�
�
82C���'p�ML�k�p�l�������[	.�j��3�!���f�Qs����'��K��.�+�d<����03"��]t��[j1�?.C�s�E2:1h/6����IJ@Cl7UCcM���eh]ssNz�C��i������LVp��.D�pE��c���)"�����U�E���)���r`w��qy��k���vXo�&�x �Rm�l7Y�H��\���k�5�l
V
���7�!�����6d���9�T���d�Z�+'bf�4p���9��?�}����{{V�g��{���!����{
��j���g��Aw�	�H{����gN��u��,.����X���]��n�.qj��a�n�@��	���o��	5)���iN��G5�����{Q�����h���cW������u�!��s���J��$,��!
 ��4�����G��OG�����a�GZ]�:I�eP���T���& �n���-���d�x��Q;��dQcr��O����������G @b��7������7Nn�5������l���j��}{nE4��B���<��$��
bN� ��5\&��1��)���?�<���	&��:%?_s�U�y�"�tbM
�3d���+�`c�O�?fS���!t�&R�}���@������d��NjUue�)V���1!��[�u�	A�{�J\Gv.I��KnH�7{��;���v{�8&�Ua�.�����7�h����}h����?l�{�:7��8�Q��w���o��������"f��pD��X�i����q�]~g;O�l'�
FO��x
kG=	(V`���q�n�b���gm��{66LR�r}�����8�X�.|���}�)|�Y8��� ��-MbH�$�����E����{����P[IwVS�X�CDDp'#"/f*����;�$�I
.�A���)�'���`{�fh2P�6;1�k�Ny��6�Z�k��8/4>�m;�Q�M����uE�&���C�*H��9�f&��
��A`.�������X�S��=T��-�9+pm�k+���
q�@��8��J���$j=����/����`'���w��3�7m��|f�)Y��c��#�0!��P��Z�;������<` qc��E������L^��U���{`�#�=�D�\�	Vr23���o�&��IX���	�D�L�q����W\��e����5%a��u�Ala�XM�K�=����>������p��*��z�<�G���Q2R��"�RkB,�U�N����::���f�>,G�8l���\f��	�V$(t\+1U�&W $���9`u����6�����Y��(6�~����VpC�(�U� ���}��k���j�Y�hL��G��������y���!*����Q�}(��D��RcJG��Jj�����frLY��0F�	��q�Z�"�	Zbw���3�Ew��.]��
B^?��Q���+]v�N_���!��J.�??>�*	!����O_|E����b���>�*d�zdI:>;;����S�$�hSmi�b2S�)�R��W����,����N��r���m�F����d��l��_�>��������i�'/�z���S����8�����`������.~`�����{�����'z�O~9_�������H���kZ�T<:�������o��+P�u��zg�o�:'��&��cY�JOxh�������/��o`�7��iA�����Ja#��Xy�7�J�"�b��RA!uH�������8�0J��X���b��h�FV'CWA:� !��i���/�d����%��_�[���ezm��;��"��	��O��q�����6�#(L�E�M�~_G�BQ�������P8)=�xb����J"NLZ�K��:�L���&�7/�,���Z�O6��$��]���LS�YF����k�TS��O�3T���Ffnc��1�	�8%?9p&`�{������Bp��r{��eQ�(�G�W���Omo�+d�������I�b=��E����\6�X*��v���,�L�����J&�q��M�I~�=?RK���~6!�!���dO�����%�_��u��M	���+�:��Iy)K���uV�D5���<L�yD
S���9����Uz�YM��x4�gJ�Z�#�
i�i#����
[E��>�\��MY�W��]��U��`9�W�P�V��^���e�4��]`��T��������M��}^(l"9�Rr�%W$�1u�������YI�a�Y���t���=q�
�V���U��u���������o�'�!�%���_�n����~����!��r������C}lu����m��%:^�������8�RW��2X��n�fg
=S�4D�D���EB��s.��*s�9%#Q����3 �I�Ih�q
'gg���L���|�r�@�)a�	��,��U��4L/H>��_
�eA{U��n�����f_,��8J���Kb�~}���IU�+j#���nVf��]���tRn�\��e����Q*
�Q�,��#�D�y������G��r�k
c�8�Ou9��s::��NzsF�	������=��b,@�H�c��7�A�Y�fbsp�]��C�S�b��|:t����R'w{���c�Hi�G��2�-:���E�������/�?KQ������>�����6Q�������uU�L���/���N�r�e�����C/����=|<��`��R�'���pS�+�'�tk,GV�n�e��!]�
{i�V�6��MUN�(���|mQ_�R�S`���T#fN����"��_�$��b??O�#k�hRt!�*�����@4Y��^�L�����@������������oX�*���������Mr� nR(�q"Y��c�l*�#(��F��ig��G���_Z
�"=��OU}��"�Q�~�*���a�H���Gk��X=��B9I$�U��l,������0�:�X1������������l	�v�l��V"v
�
)xj����;�L-���g�3�xl���M��iU���=%4�\|�/^^r(�8l�p�:�����T!�(�U���>�\�R�-�+���T�-�S����n�'��y(�=cA��g6�ta�,cAe�/Ae���b���|>B��G���w�N����|��uDbf:��t!GRQ��<�=5�(��T.[m��J�%.�Z69��l��L���{d!��#�����lv��lP���c���S�-Q��r�:wV��R�/-I��!'�lX�����J����	1	���|��d�q����Wq�gEr��R�>�Kj�����Z�������j �v�3&����u�&�j�)�eR��9�����������N�������u��rMx��n�|�O�|
��z(��9z�����Z�F}�S,�gW�0�����%9�����zn~�<{v�h�Y`�<� �%��
(���K��Z��,3/8u�x��(�:����(�9�;�-3��l<�Nu������#/�,�Ji����&��l���J%��a�h>A�$;/�l[��V����1�o� Fc���h����j4Y�������&:���R'������;��t����0�h��D�,�j���}zj�Fn��o4�zI�x.K����$L�A��>�7����%��b/�.	��6�@�^��ou[������
� {@�����fc������P��n��ob/b3T����*�&%�%u������>~d
��Q�
��������d�����i��G�69��u���(0t�IH���P�`�l��CR@^��5��5qY�e[2��z��d}$�21�C�Y���C���@�����6��|*.�d��T��Hh)���N�������@������Td'	�9��!d�����I��s/b��7Am�{����'���r���?J=�Xmj;i+��os���6^�z��J���n-I���H�fj����W/�D������'g�� �D5�
#�O�����5PF�rj�	�[t�c#PB����A��P�����2�~hp�~��V�-��r"=�&:�3��r�-�^���
�4���W��~z(�mV���E����u����a��
+c��K�s��F*|~��A��������=|��������|na��wF�����1�EoYx���r��}��������/��jQ#�������''g��2JifHf��G2��o
;z_<"���m�*�*|��G��U�We�F�GX}t����B�C����x��[��Hs�"����/�����}���Da�
�V���2&�v��	���s-+<O�F����e�V]��d2'���l,($
T=iJ�~�w����#��$2���o�<��f�0��uB�e<}����$[1��7)w�^�2���Rr��d@������|�6A.���:�X]�}(�~���Ci��4�P���fj��)a��lm��8�P�--�fq%��Tg�;��\iV`��Y^�-��dM�)��@��,�0Z�Diu�OU���6�L�!p��"*���k��I���4t��C�zQ��M`��O\U��9�����>����!]���z���D�-����sYR��1lX�a�cZ�l�	�53S��z�">Q^�cg�����
��aH��S=~�f���,Qd����������\	����:C�k�������>�x�.�U�Z�������#j;����Z���������)�����������)�.,�U�k�L�g):*�;S��Y�b�b{�R�j���m\K�ud��]*y��+>^�^`��`>�KL~�a���}���,H���a�7�R����� ���m���G��=,�(��)���M(z��}���x�K)qO��7s`�(�o=�N�4���+���+�!���l����L���U<��!U�SH<2=�_LkO�t��sz���6]�s���BJr�t�8+���1|a&3�#��|������8���w&��J���_������y���O��<����"K��N�2��kW����������'8A<����8�w����0�R������������|��r�*������-���Z9��5������ne_����KPQ�8j�2�j��`�����E)
�?�EN����9���q���J*GB5F���wxzWE����0��}EIQ�{��u&~.�[��I���O�&��og1.���R�^�������K��5���O�����XQJ�K�#?k-���!�$Y\�7['G_��w��R�r19��� ������
T$G��h��L�����aR

����J��CmP%�W�I�'�S�D&��Y�{���?/��������1�*O�v2���sQ�?��O���Y� ~qO��
>�(%��x���2�~��?X��Q�z�H��-�c��/��W��>Te�U�����V[m!�fu���f����Ss�v��������7mo�F�?����;��%��n�x�,�OdI#�I<�y�piI�)RaS�5����Z�������;��H6�X
�BU��E}����������gQGZ�R�0(A��^��Ho�����5Q����f����k~I�U��&�R	��_2�k$�|-��BJ��@�9�Z����J��7}<��y���6�w2��K���Q��� ���#/�/�;���*R�f�:hs|���~N�5���F�R�K$���*�����T�.���k�^
��E�NG�h�TX�<ydc%n���v���Z/��&�rd�ti7��!��Nl
�	:���h:q����t��+m/��I�Q��
���:���V������^h���MI��IA|�nzN��/,��Ng�x��u����j����T��2�r@��CY�{t5�%���@E������������4[��i����\����p��������u4�n*�Rf�){�?��l��\�yO�NH/,�������h}��\ab)[�F��`�
���F_bd\Ot��b�UO���j���������mW�y�g�U�����r��j��Z�^�Q���k��Y�0b[\I��oh�x�M�����D�
a���iD����$Z�(�t�`��b8�b����e4�M.nz��q`�w�4s:�@�ED*L��R5
�9y��h��=\�P�h<�m�+J����X� mNy��FarN�09O,=��a��eY��H/�h�0T�;�%�=Y�(��f���E��V;����a���O����^�������%B���9h���A����7���wN�������M�MB���Dm��}%�wS`�'WJ&`�0���3h�	��2��:���P�'tr�rp���4������"�]:��(|�0�0gYM�[���Y'jwNlm\�6�)5�{�P��A�p��)����}�6�@��e[	�	�>���-G3E��d.��t:��N���Pp��&J��^��@�h���7��4�>�"�~��A9��)�/��4�\N3;�����w���r0���o~9Sk�����_��=$
���lf�G�^���l��>��7���PE��ECw7����k:�����>M�J����;i�u���^�t`?�Z�]p���[�e��N��m�s�G�����S���	�V���T���@�������Q>�|�����)]I�D_�����E�����l�SRUo����q#C��������n�_;�P������8`���9�j9\�N�,����r�0HRJa�_3�8*�[	d���k���|}]-��t�[|/���_������x]�>�:6��'l��)]l@{
-��h���m���;k����&�_�"Z�/��l:y��'G�3�8��i��T��>��{�`t���r�ucj�-�g�����UvCL-N���v��
�R�\'^A��x_)�$Qtq�7�D�s�b�jc�g�kc���<��������oQ����Q�*�u�H�Y*3;]�&� 6���{���}R����H��_oF�?���zW��� ����Yh��IF�x�B�'X�,H�~���nHo@�~y��M���i�n���dA���a����G������%AJf��)�?�S�r8��]�a~+��$G�I)OJ�=�-�A����#����Ch���;?l��s�)�)zt"�>����{
�f��_&�	J^��F*S�8���(S?��g*��p�2O��v�h�a�R�.��?,[��uf<b�HUg�;��/�eu�z���7N��a��+H
i�Zh���U�_�.�?2����Yt�_pWs���I���f�����j�
������e�@^��8����[�C2!���J	�7L
�
�����O��W{4������L95�����v����Ko���������n����_��Vx����`��oO��qR��
����|5�d*��A�p>��]=�(I��kg�;�4���B0����S�#x���������jRw�f�K���P�TV�/Q��	��k��n&�'�!iA��?��G#�}kSh����}���#�G`���� ����5&���n�$�(G���>��B'"uV3�]F�NP:����P��������8��7�������2�l�����������mX��)m�5 �7�~�V���d������z-�ry}���f�X�o��7V��4�5�M����w����[�[�o������������d�/P��P`E�*%M$	$"��z-��gO#�p�_V��\�E��rT�V�I�Ako��5�~~��^u�u�#1�)��O�Y7���	z#��<4����7#�v
���k�
�P������v��Z�������F��u���}i���-G����+�Y�v��Y����Y����z�b�{��P�'���N��x�i[���(qcNJ�PB^����OO�g�����<U���n�k����t�m���8j���E������<������X�������t���q��Z��h�s���wu�t!�	�B��D4j���ZjQ2�W��g�a�g�s����,����>�z��^' ��kO'���?ZY{7PN��T��7�
�m���
��r�?��>��>n��/�pO����������X{M���,�%�hG��s,��D*�G�Eox=��5������l]i�B)�]�Cn��S����=�1��Q�����������UG�
�"a*�_ba���h��Y[����0�������Y���O�As+51��K8��l����o�����G�CmzP(���KxP*�G�GWp��j��i /��I��O������j�N�c$RGK���?m�D�����}_#RA��_o Z^i����I����S��t�3	���^����!�e��Qk]���-��I���6���F�d�����Jm����<��R������e=���V�Ph�k���%������2����u�o�]�:�hV�1H����w���U����cu��n�C���_`O��T���-�������/n�����~��0��v��aR1�}	F���wu��@L�p�P�?�������o�M���������$���2r�!=s��1����E��@� ����9A����s���"�`�	-WM��3�	��p���B����m|��������w�Q������uoF�h��9����J�q����&��}����\-�	;��/�v0��w�91�N�%���v6D���*:���5W��E�3�/���?��60k��f<V��XV�������6����{10�w�Ff���^+��`����Gf����k�_����{�P=�w�Z����o��Yohr��7V�*�aJ�{�K�2r>BT@z��P8��E��:���N:�����$��_�7�������^/m�N���ofZ`��$�)�P5r����A�4��Z�"b����.9!��+�c��M��I�������/��)-��Z��;����/2���������J�J�7��������#��Y&�'��*DK��P'V�G�?����u��u$�^d�]��V��ble��t����)?zG?OA��l�H����{�dj�N;E��U�|�@�h������P�F���b�	'
q��dB��7%�:�r�p.�`��j�������g��8���n�lH� ��eOp��w��
�s~��?����'���M����nC����n���]��]�Q0�����/�����
����y��0*^ 6k_���^h������	�
3�����������>���������R��q����_E�M+�jC���plw�fFO������E����
o � ����['�����<��}+�$�v����)z���1X	s
�d��>��~��"r���>�����E/����`t?_���r�����:S:���ZQ��b=�46w���<��X���]�9�YE�[��F�j�1M�[��r,L�:���7�Z��a�
��&�!���	�j���S��i��{��2}%��r��QJ5X?�*�J)�+�~�x��MO�~���3m��t����+�oyz��}}����P�Gs��\lj��-�b$E�/i�B1����k�^4����pY�f�.���5p�����L���!��XQ�������m[`lGs���a4z0�����Yk����;�����y��I������
����������;a��%����/~�j��,f�)����W�`��d>�M������������~AnM���$s��y�B�f7��R0GV��G!\����Ig��n�������#f�\��F�I�vm�SQ���.t�.��D���8{'�z:\g���xf��DX�k-�E���(��T�j�vXC+��m�����t(���e?\��MW/V�����!	�R^!�<������=V;I������*�z���{������L#������`�y[�������7���9�N4������;����Yi�^���������$���U:G�H�h&M'9�-�x���@!D�B��~6�x��M��^�D��e����I]��(�U�Q���U�a����<�z�%��B�jP�����{����t'�Y^�"�V����?op����0,0���i��hloo�o�7��������4���������F�n`����pg�������S"OP���J(��Pv���;�Z.?��e�M�-�3Q�>������N�
��F^������r�q���S57�p�]RI�w�Y��,��,�k
�sE[�/���-=�L��N���(q"H9.O>��.Z�1�+8�d�V����*�����S�t!�g�b��)& ����eO�]�qZ�T�T�|jK���	�����Yx�E���L�������t����~!��R����lC���p�>!>������m�C���<�v��_~���>�Z��"�k@B��&[F��Z7�cE�T2�e�X�b�PJ�i�vp>`���`�-E`
>�b�)}�c������zW; ��z����^,���h����doK���2�)3=�4�k5����
����?�0����y��WD���;Z��m������F}��]���"���p�i��p�o*��$�~SF�A9��'<��~O�E��
�������b��1����]|�L�BY��.��{33��J��<u�����.E<��r)���H'�6M��a�/z�[NX�wGU�D;��;H>:O�p_�����
��" c:P�=��K����":?q�~t}
t��p�O�r��%4<?�I7G1UV�GQY�����Sw��������?=�W�� w�!d�a��������F���(|r��V�}|�^ ~-+�[����:�L����zo�6�'��Q7GY���jF��J��]�`�1��x6 R�3Y��(FO�^D2��������W(�9���2��������~���NatKb���R�/�t��?1��Ca\
��&#����)�+�]g�'(�{�&���R���BBt�����x��	��}�?�>����6���X�Qy�O���Q,�h�VW/ ����t�$���.��Ot8�'����z}R)��$�}��k�O
���;)����z���������m6�w7�v�����������E��`eee����jk�VoD+��Z��q�y�����v���D�s�:&��t��v�����Wd�U�A6��[����$�����\�������==k�nuZ?��h���#��������S<��Og����z�6P�*��k�;�;��m��������S�ol���Z�D�ST�cs�����Z���M��a-��G��	iU.��%���x>�$�����+(Y�K�d�3K��+��8�M��e,U��|w�`�����u@�d�����0j*��P��_\t�V�@�
��=��*��H�u���������:W�y�����@���h[��������P�t:�M�6�UL��=G�d���c�.F���?�G��:*�Z���O�����i���z�����<�����7\F�F��F��'��}�7F���BU�KY��A�H,��\O!;������<����o��zU:_1�o���M\lS���1%0PP�S�85�����X�o��i�x-SU%�xJ�U���S_�X����h2Q��4�w��"�����T
��)+z9���������f������&N5��$���',��=���
ch�=��,��q���9T��l�zmd�g��Bx��>����2A<A�2]���SO��;:<9�i�b~�M��
4e�$Q��&�t���k���,�
o�>��F'����Z��cux?�����z,A�!a�0������z���h�6�����+	���e>M�>�~{�����[zU����^
l�UoKsom���-�����[z5������~���7^��V�|�qW�o5w����~�<����o��������7X����p�>����n��z��G�B;%s���p���m#�����+�t<��S�?��6^�mFK���V[�����j��x'l����d\�]��-o�%����u���z��4��d9����t��C�����gh��F&������f[���x�Ei�i������f��6���������A�� )�?�{���wh]M
5)���(9�����7��S=~���=�j����G�^R����K���-����i���9��*����p�rD�C,xw����E�^%��g��f�y�?L�Y^5���m���A����	��A���w>�#�
=����YQ�+W;���R���u8�q�z�8R���s�!*�j��x�
Q'��x�q<��_V�Q����L�������(�<\���V�^1�x�`��
���w�\���A����:����v3z�(zHuH�]�~��P�������:��$"��6�<�?���0�#:����xD�A�����H����q�s�&���=\��a��&M�AJ��F�eu4��tPI�4=� ����f"���1�TJ��g����o�d4\�%���,���2qopY+|����^dM���=�7�1E�'hP����;���g��b�7U$����J��j�V���T>�N�����d�)�4�1��o&C��KK�"�M�s�<1�r�c���W�c%,yV���P36{H�"	{"���u���E����r&����`eE|6�VK�YJ$f���`0��|��s��J���%�A
��^#��QA���f~�qq���>��'5�%�f���b�K�����q�&���[XU ���0��_�����J`����h����UE_��������/P�
�c*��G������n$F�<B��*z�W�m,�]0[A{���������~�yY��������!����!�#LB#�`���e����k�?�r`mjK2�>�S[��j�y��j��VR��kb�;�?�@��	��TG�J1��LI�����@�4\4@:�"����VI�3��p���>�`�ar���pV
%���
��Q�k�f^���TP�����S�� ����,
�����p���DMWz5�]�Yx�Z-�K��li����V��g�wF�&^�[l��[���N��N�������.1_��]v�J��a%�v%�2j:�]�-[o������u�^Y`zBi��� �W����0X�����l��=���G�;����&���s�����F��������eG�j������
���^rP�d!��Q�;�V=�������L�0������,�o�j2���s�����p�di��8�%>E!l�ZkP}�*#��_]��#�������|�,P���-���P��e�M5K�R����9�R�q���Y�_9az6����$Ex���8�kp��*
�{v��@!��z��v
R��~�>���O=���� �XS�LoXYXA%	RJ���T�W?
���}���j-������\��2�������'��T�
��T[wJ
��d��ec���1]�U2*� �Bf��%���h��c"����<~��Y��Z|=30����3Y�J@	���pO�G���D^+G����/�3�&�i�WG�<����F���5�s�s�YW������T�����<�^]O��]&���J-��Y���x���0�T2{�T��f|1S1�U���B�<�E�/!������m�;
A���O�&2O/*��-�Lf��\L N	
:xn>��
�����!P��]�u* jy{\���.�����6wkswc��[�kk;���^c��s��m�i�������[;�F#ZQu�R��bg�%�,�
q�<��{���!=�Z.��H^���{jA�\_t�g��gZ+J1��WJ!o�':D�W�6D�(�Em������Wx����{z5J����7/�v�'`�����T
_J�6I���k�iY���m����w7�[:��T��Z�x{j6�O�l��4�����K�]�������3{���~^]�����������"~wM��+���|Q���,�Y"m�%8E�=:�o7��ayuv���u������A�/��u|x�c��������1Rn��� MU`
W�EP��z�����:����>V+*�fZ��o:�����w��^�kd���@�}{�������7<.�(6�Bx�1���XM�6M�bfb\����">k�X���8�a�4��������^�"�7sj�]�N�~�)	O ��J!�@���]�L&c�##��
M(u��`���(B�7�� ������ac��W��kD���`�1}���Z�Lv]+`2N�h!0�i
����������K���;��Cm������NvxB����� ���n
��iJ5�B��*�coiuI�_i�u_R�������V�6���9iF�����$��,)�K�F
������$�Q�8��m��y{����%�~��,��KA����}1�f�"�wQ���Ow�k$���
 G�����gMQ������Q�y#����hy�T��<�h��R�����z.<~��E�,�P�fF����vV�&��A&��aD6��-\��)��U���D� �3!�@eM'�[�Ld�5Q�6��T��|��h�p�a��g7��'AaH�iDe�g�x�vo��DY�In;fdL5���7��I������g��U?������XnU���.C�J�
we��E�����W���9.�AfCX
����(���ez����(���6z��p�o&��3Fd:����h��I=�=$�s�@w]���{5��@�/��#����FmCq��{���zC���e;�Fd�^��������q�:�gX��1CG
������tv�<f��3�L���* ��q��9c|i}���i0�O~����Fqd��/�����\�[��,(-+`-��;YH�fX(�#�~��j�����,����.��.
������x��]\#P�Z��L9j����P�lm�aW�2�-QY|_}��'��+7czk�z6��"��4���ScXg!f������W;
�{������Ew�u��� .����	�W����/_�Hp�k&-��.���[w��_Vf�������iH�����v���p�F\AU��9V{K�J�i����}�����k��4����j�pAh5 �qZ�@fG�~f+p�VS�/������;����hX� ��^�����1�������R�{<}=�����2�����#u���fB�qg�2#/��J��M����M
���
fd���+��O����n}�y_���V|��n����������Kg<�"��?_���M��>�s����#��{�g^n�V��~X�g��B*�mD�����({s��������XCt�rd�u�|������F5T��b�Lc	7��1���&���z�o>e��b��2w��s�� �vJ�|V:�z���E�UR�}��[3��:���zGc�?�B��Z?F*�����\3_����G��8��N�$�#�Dh=C�xl��=��1����u����U���lw��B\�g4�Yo=�m ����Mm��`�9_G���>�+��,eC���B&j�=��=zD�tP����p�~wq#��c��mW������{�����L�=�,�-�6j/�M�r����#"����o���
��]M�$�L�_O�o���r��r��=��\�8�
KTR�uk��B������Y��~<�b���j&��v�1'�f�f���ti�c9����gdb4!.�!��	�	/
$����8:�z������9&�Q3�tY�!�3)f��
���6���b�3���x���
�&�h2#��IH���)��f6��Y=F��Os���h&a
�����y�2��tu�Vy7K�O|����r����^���+���@Y ��Y:���T�&�������W�Y	�B9R���	�F��W�E���!�����fv���;�����w�����g�n[�[:�-�T��hv�<>��v��C���`��] w������>i�!�T}d���� ��q��m��r��������	�}�FI��a�/8��a�����xl"�
��ki��i�=6���W&��R�����_/3X��M�[�u�4�����Eb�������t�t���8��&������������u
�IU
�����U�M�y���~��<���'�Go��#k~�C����Q#�����->���	�����b@0�����j��30CL�X��Q�e?/W���F����wu)�5�f�>��Jy�d����F�"PEpT��~m	��6'���C��KQ���i���o���hP�#����q�n�rN� i��X�&�?G:8G5s:So�`��T4f�r��������B��+<��4����2f5F��+�N�u�&`�Mt�Q���?s�iw�_��k	M��+;0l.<:�"���'��6u��U�^2�:��4��p����C�}���B3�=�O��u��E}�N\�]OS��Cg��UC�<O���� �a�3W������8���7����:��c����������`5g�&���Ti��������y����E��
�$<f&�[�h:ro�gq2��
�0p�2�t�h��)F���rq�3��:BE���hJ�PdaLv-���Q5|9��:�*�e�� 79
+N�]EH��������t�&��'��8p�+�Q���T�~�	X )�<������gT	�e�8��)1�"g�"�MtT6�9�����,�S3
�	g�d4��~��$"	=���id��LUM1q���d	)�]=�zx5�s5�����I�9@brdg�
!����P:DS��ji)�$�z�(�tY��`�s���}�t������N����`��s4��gPnx�0`����t�|9�I.�!2����t�^
��x�����,��-�;�N����+���b+���5zH�a�
L��Y��\
jB�!�Z?f�^)A��6�
n{����*N@�*h�8�aW��9�[}
@�QZ��	G�a���V�<��!}p���m=k�|�����uyi=���ZIC`����f�J����Mk��]�M��1�d����J�
�&d|�?���S��p<L����MQD��
��G�,���W����� ��EK�F0��z��>�	���fx�x�J�bH��P.P9��J�����c��QY�C�7���.�a����\�V\/���5����d���������6&@A]m�jMGOd�~�Dc*f����_�XV:�M;?��@���?�9g0Ve���S���(��~Ki�����GZ;�k2�{AR�|I�i~��p�ke�1�C�
���r�M�sY�cii��"{�%4�6��jQ���b�S�c��{���a�
��%��r
�j� YR�i���L%�j�QH������6��O?Em��%��$���D�(�zD��A����rD�Z��k�w�t�/����N�����Acg�:��3P�������~<[Um��
�0�T�tE�=k��M��yX����_%�eO-��p�)m{��\5{��������I�mpkN�vg�|z�\�����K}2{=��2�T�e^Q}{�gC��[���{�Tc�0R��M| �*w��N'��#�8��wr��<���q���a�����YK�B�Bf�^����R��E+��u�����N��+�7!Q�S_���xq����J�ehf���c��������)	�	��kn0@�3yA�W�������K
]2TI�	�0��y�������<�T����:b�gC�lO
z7l[=F��>���3HE�dLYC	�����U$�k��'v��1�<�1��]�����M<��vEc�j�����B�R2���C���zc]���(��_�Q����o��x�x�#9>&FN�P����XD����x�I��tB�u���u�JeX|�4��
��Ua&���_�G�_�.�]d�Z��f�.Ee�����u�PC�V3���Z�!��I��0c���(&�1h������M�A�g�u�� a���G��c�7�n�|�����fZ������ULEb�g���S�W�����t��<a�����f�������Yd���8�?��M0d^Ps��
/i}	�r���ki�5`�<h2F3e�H������0L-0�J�Q���bq
�>��%��;�B$�Y�e��<&����z��#�
��cLD���P�9�r-Z�7������tn���ds�U�<�\s"}��c�Y��>��rh2 �f�����{��o�cO�#��N��gn�c���M�	����|g}�3���\�3�r9DF�o��"���:�|��n42��?�Er�C�e��I{{��;[�a�|m�|0�����Fv`����a��jbF���]���M���Z�%<��).�J!���~x��*_�*}�.��T?O�����`(&_�"���:��c���;4�v�����bM?tEL�]/nM�;��7b���� i�aU2z_��n�W�]��h���H}�bk#�#�[���
���3��\�r�V{�;;���������N}���Q���V�v�*]���:%W���L���J'��������RJ�a�����Xr��)l=��1F�� �� w�:	���������:���#����H�o��|����Z�����a��
��`
�����`�����%�Y�^�(8��fb��7
a�+ a�
`��<DIHL
	�c�����56��Ji`������a�`����[�	
S%:u��s
T&Xv���B�a��2,������Fe�V���;����xF�Z3�.����	�
nid�R�t�x�P����pJ�;����Roy�J�g����Iz���3c���J:�_`t_���$w�q���+�������H|��K������z�Z���E�2��}|��T)��$�H�6U��v�T�?���@���j�l�0z�{���e���w���E��;������2��U������h<������4�X�{>�����0\0[=Ma4�b2��b���������-2\���L�>���:>��1If��`Tp(�i�IR~��E��j���+��0���S���W���}�B�`��M�K��t����^�������<�����jiH�5|��[�0]+�~��bP�R�XV���hf�S�����p�z�b.����;���5s��"��-�T&D��B��J2�+Xy�Y��q3��$o�@;�T�8�o1P�{K�������AJ|�^J���2���Bq��cs�]e4�(L���a%�y�4��bjN����?�4�N�H��H��t�H�1�e���/:K"��QCD��E��_���q&]h��� Lhu��a��R�l��Zf]�Mwu�Ei/$����9'Y.�J��?���[P��Pd�O��7�,��z���$,������$<~�����i�������B���@j
��_W���~��Of�\���:���w��#���:�����f�.�6�l-R`�Q<�;���o������D*��z��^����l �*`��?@i e�3z�8z��� �:].������e�0�����������������c��S������1r����:�{�J�j^0�`���gk�.�j�u��:)������F�aV;�F��)s������+j��Ge�%.�
��:��9�JEMj�zVkF_��w�����S�lJ���pZ�^�����j�S'��z)���)l
���vH�X8IOG�9M_aW�a_���zJ-S��P�XQC�q�jKrlE�i�9�`i����FJ5@�z�^C����e5cx�����1{��8.����c�@��Ka5s�i9�d�i��Cq#g�#dd"8��EfT��7�q�����T�xg{���1����������v�!��P�%�S	X��%�Gc9�.�)eI��E�����"W
2�b���[�#q����L�a��������g�9'P��GQ�R�)�� c�1��'g6��?�,�d`:��)\�2n*1�{%g�y�<<���yz��h,4�B;#gB� gF�q��4r���-2�,���Njgb����/������N���N���;Hc���+xG��XR�/�s�p���9XdMmREk��[�`�g��s�l�L���?����s����+�*�<{�`
i����C�u(i������y,���!:s�x�����M�����yz%�Do1�]�2D�n�U���{��y�����(�.>��
0=_*��3{i_� !+���T(qmd%��Sc�/�(�.�{�;B@k����A>�r���"2^�q��<�1��'w*��\A�g�%�]s3{Ga*lSf_�X�*�d2kI;���v�
r�\\?g��I�po�C������6�IZ93�h���d��b2j��@y�uL.0rlcRT��5��,@�� ��%���xI�F/i���<l�,3�+�Ri�]!��3��:ct{~s~N���%=A��F�EG+[����('qU��I�n��/o*�g:���(	7���Z�/~=�+/����'����2/(����o(C������(3T\Em\-f������
�dE�e]������r�Yf�+��9Q��;�"�n��w������z�Q�X_|���f�f��w��P���n��*�"�a�h�������R�q��5�Z)l+x���,
�Yp���_(�r�Ev�|[��<p%@��1]�>��H4O)�J��$X7�]M�r��\������q��6�m�l��^���l'�bR�jP�Z���(B� �?��`|�f��HqO��5�
_�\��~c�R��R������h�<�@���T8NnL����x�Z��mD+���Z}}���Copssuk[9�M.����G��D��)$���iJ	c�H����"Ht����+�x�j�b�O��R��((�����t����a���V�FD���V(kb�oP#}�J)�D��r��<7������$eB�*��3~�;��[�U�� `u��w����gg�+�P�������*TB����Y|Ewx��Ca`Ue���<8|�}����E&Q
!�����h�gd�&a��b:�Z�o�1���I�?]�B��&cy����3Z��-�}�
���F��00�N>��y���u1h30����#g��W(�����\0��{�����zRJOE��w��2@������������gE������o����zy�A@
�M��m���:�*ar�u��<��u���uN;���K�k�j��<yD�,cM��g�M��{�_�p�!������q�
F:(�q0Y}���X�D2�����
t�4��& �(p�C�F�0HUr�F0��DeY��f�.����n��"T����EQ�?�����I�n`w���\*���/./:��u)��,��D9�m����`�_�][���������m��,�M���\[�����BYXW�,.8���7������L�H��2���Fn�}	J����������<�o�hA�&:���P���#��BO�F��������#<�J�����Q�s�Et&��������a)�F`lw���H�@P
n�1�m+m�U��*�&U�i�wQ�k'�5Qdc4TL?����~�E������{n�bt���z��)���t�E��pq;�w��41]����Y����D�w�zE
���;��o�TGY�B	�E6��t����vQ8�LJC�C����j��3b������n�6v4&����I2������|E�\��EPe�:R8������V��N
m���$��;4�o��.hL������&��1��$��)'#U�g`���c����3[����xk�~9���f����
d�K���&^���L2��}f.L�^l%sz�e�GX7r��z}�
�
�����GL�R,U������8�47;�'��d��Ry��a
]xO)WM��`������-�v	y��%��T����O�)	�T�*�lW�5�](U.��2��=Q�~-5��%V&Mnlj>Am�kw�US��V0�R�.��n��e�3�KQ:��T���:	����m�7����or$w�y��}>[�� �Bc������
�:����ZwFY��r|w�K����n�)����;
�E��a�xK'zO��V�G1�f�)22�4��������|~5U��f&�MF�U2�������R���[fk��B����6R��gvGD��:r���q�L�O�'�������q<v�"llnl�v�iO���Yw?������Q�`��� wA�MXa��f�`))����tb�Z�3_
�����-,�����=k�tlc���fL/N��E�(�J!�x�����^
��=�D��Rg������h����W��[#�!n�6i��V��(�E�a���7�h����n���
�s�f�6��;2�Q^��m�6����e���(zL���Rh������ih���s������2/-����d{���T��
0?������o�����=�����6�������/���n�,�����2���E����nm'��\��{`��1.��;���g��S��=��_��7�cH�*�:�v��
.u������T�Q��h�9H=�����$<��#���&���ZQon�����f��M�����y���:����a*rx������G��U��Z�����KZ^}����i���\��wy7]5�d����=s��7JL�C\s%���[V��|y���L��-�����}a�Y,@6����������,��3���7A����������������b�[v�e+��KvF���l

�f��e�V�d�p��!d���^��y�_�� ��%����������3	/�;�RD#,�7���"�����+e�G�T�B|T�$�y�K�B�w�����?�aH�~��HM������y�����~W,wE"�R��A)�I/F�0���s_~?0�:2\�������Y��B�'%���V&L���BaZP,����b�&�`�I��^�r�'(������X�#����	�</��#!���p3�����$7�v��{��U���P���u�\������?i�Uu�$(1v(2���v0���Y�'�������]�oZY����n��i0�1�F��)���Rg���������_���h�?w�t'�~YH%_c��(@�C%s������*���qoa��{Osr=X������������
���#,��`�/\��#�\�t�wtI�Q�3��@�����N����a�W1�t�w=3�ta�\{w�k����c�3���I
���;��i�ew��)T��^�0y���rj�`l�w���_�i�>�	7��f���s[%413�]��l��i��lZ�{�V�7��c:L����.1HW����w'	���F��n�S��S��4!�Iu~e�(�;��ky7��=����~9�H-GZ�;����/[07���u�}������x�7n����g�E���Z'g��3mL�_��?g*n�1�l����F���u='��<����T��dCw���B�x�wA+����-��T �na��Grw����7�����z}w��W?E>���,IQ�Gw6��zT}�����x���kM���"�Y��
J?��:^����,w����~b�<X�>��[F�v��Bg[�]��i��{�������2_�P�����N Ay����Sumh	���1��nN8=a���
��=Yy�\0��f���q���;�p�D*;i��SI������=w"{&���`&�k����,s&�
p�<O�XdO�SV�L.})[0����Y�M|���ut�T���X�8����E18������Qh�`CH'�lX�7�pn�O���-5�f&�=$�^���Q� e��~(L��l8X���Y���};E%�.~��Il�r;%�K����������� |��|f�
���f��AgK������Rn6�v$����f	�?����M�G���M`��^s�ZDqO�gje���R*�l����OV�U)��9s��w�ZD�:��z����{�;36����*��b�$�d(Vl�����l���������>�a�K��1�Fa����ks��[��>\���e��������j�G��Z���MB3dF)$����K�.ZX�n���[J�����.���\h�v�YKY�_�6SJ��sS�-W��b
����B0��1K)�\*i���0��h���Z��H�Vo
��mQ�����N#�������7�������+�e;Y����������6F%�B%O���
;����=T�P��:�8�e�a e����U�������|>j��!ba9����#4�.�C�;�v�����������-����c����\ �dh,���&fYzbN���y�c9�sd���&:0�f��P
rO�3��s��F���y;5--n����^�8����ciX���������)���y�Ba��!O����yRbNa|J!Q����/x�a����"z�)t�KS2gV+r���,�3Th����#z-#m���6�gK�S����C���%Bv��p1$O�U`��;��<&%&���$ {
�L\R��`�.,������_&E�}q�DC,G����Y�������zY�"�ZRO*�J"Y��
M����U���jL��9K�p
�7zW��` ���F���\�f	Fd%	���|���1mxFv~1�����"Gnc����|WY>�?��`g�������7��kQ}�Z����~��^K��.#�-
V?�!{a����o������[���,�����!Q�5�[����6�m�jv+�Yg�d5it���4�Sfc<���v
����e��W6���jq�d�9`v���
p��h������pIt�N$>���]�h$�wymmMu;�*y��s�>�V�u��x�v���4�'�gJ����/��vv .����������z#��=���6 �.i�67j;�
~b������X�9`���`#p�!k�n�J�+T���#�x/9P5��w��OWcd{E��qgz8�����U�� ��12��}��a��c�<�:�;�����2��$�}�������'��|>���k�c��o��q��m4���N�����[�P	rl<!���)�#R\����{;�����������N�"y����W�8��`���S<�Q�y��d���Q~��XB�x�w=��^��Aox5��M�=�Gq�k{��(J�f4��&�T)C8T�%�W3u�����S�Y��,�^"c�_z_��`�|]|v(��n���Ec2W�'��q��U�v���C)�����<3���^p���]�M,����,-���A������|\���(�"��oI��:]h5����1u��&&�
����ghZ�������L���������X-@e��9��x�d4\�������=>���zM'� K63������|J��dt���Z���[)T���|�����X��>�1��H�mzA���x~;��h��7��1.08�>LN�B1#����6��Y���G���k�]�5�9H#�����~�t�����i�6��%(��a���
��w�u+y��G��U���j$��=�{a��y��{�p�������N�$�&,���l����hz���z	�\�����scw�^��R��O]%���q�����l�"�ja6�i;�Z�^���@T��
n��H��z3Iz���*t��z�'�3��'R��p�P�0��0X�O��A�X�j�Y��R���0i��;v���y���V�CPQ=���@:����Q��q{�e�Y��T��\�L�JD��=�^%���@��N�����Y��)�[{����YkP�Sf-��pM�C��!
bdKo���oV�C�`������*�!}V��/����2�z�T������4;������2�������K�����@��/Iz�.�K����g���T������������E�)���Vp��1��t�<{ #coy�9/3A�(������Y�j�����2f�{��zo�~������y�\I�9��6���[�sX����'j�z���bf���0�	����rS���5X��jL		)�e��VG�����
x|�q����c;CD1J66���������#�1�y�>=HE�����#%��'�c?�J;���F����Q<[�(�����	&M���E��T�,-�3D$f��Q#����gep��g=�P�H6
/�/9�}H������"c�_@���Q\��a�������DW=����$����o�	.����H�UV������ p\w���1�W5�|	xf�M�]�y�����/�<,��'������2R
w��S0�(��<�It�����xF}��^)�;�'���y�`K��>�q���ZlADE�h/����!��W��
9�/�iL�7W����<0`-�tA�:�Z1���Yo+������1���� ��R�`?�4����t����-CB�z#�<���:�w��w=��KT7�U��$�������3d��Ce�����r����tZF���0��D\-�m\6��N�Y#l��&C������,�&Z
��T�h�:.�fDDE�����2�����0������sv������w�I�|��1W$%�
)�l8���
��,�|c��S�6~�1r��/(��g
��K��
����n;f��r���73g2� ~N/��t��&M	��������p<�`��9����
���10]"��&���
A��"5D�6�4��zb��y�_���`3|����}|��{��:�RX�KK27�G������:�'�j=��,�)M���CW�8R��p��J��M��#Z>���#�'��=6���� 	B?������^�B�K����F����s�G�)d��yF��!������|%�U�HM|4��n!]l`H�$������W��:�#�����_	D��{��89�tO�g���M�	_�����{�h����n��/;�3���F���E����_�:k���4���#�_�D�QE����o����Go�M��|���F�gg�����>�fT��V�����n7���v����5������f��u�wN^���g��;�8k�xCx��������`!k{������r�@���O�P}����������?:y�y�����{�=�V�h:�������w��{�{z�R�88R�QO�Mx��M_;�?j�T?'GG�"�	�T��������U������KF|���L->�~|���LU=z?^�^�9�-�<jt��/��!��e���sr|�<�O���}���
�=����[��M����<�>���[l
 ~�Dh����?Do^��4(=��1e���8;9�?�j5^��m���
�a
��:(v�DT?l!\�������G0q��`��>,:������������
j8���7��������	�6�r6�������a��|9{{
��<>��7��C�v�������y
����QO��:|k��n��<����I���>N������D!�����[�����j��C��l`��XH�	<V�0W}����/��A���R���Q�x�B���j��{�:k�R�<:��O�1O~���<9S�S��U��������/��Mx���u���"./����_�j��w_+��H0�W�����
���N^�)�:�W ���wP��9U�O?~ikR��Q�S�����R��u|��������/{~��3(RDq�0jS�N�X�����>;�AMV}9Q~8�^-Z�������H�$�K��(/(�����`'t����8�_�R�����@���m����i�q
��������<�-�p�7��W��H��V����G�/�G�����7������+�KuRt�C�u�������������%|S�{�|	~�fZ��&Z����
������� i�ww�T���j���I'R�}CU���o�W����}54������������\o�PM��%��nv���a;:9:��B���{r
��L}��A��b��@�h)Z:9;T8��"i�����:F'���o�������s���/o�����w�������L����Z�d��_gQNO�x~G�B4q$����g
m�T_N�������z�-h���@����:R;�
w�!���M�
�z����u`�����t���g����ii����� ��#�>��!�?k�����HW|���f��e�z��SO[�����'P�`S��M`�T����q��#�V��h��>�h�@���F�
5�X�F����� �Eg�W��Z�s�?G/�a����Et�I%��^:��S_��h���$f�X�h�Oh&j7���I��	��m
 d[�M���T�IA�|iC�L�p���g���<���i�ChA�?�G���w�
��N~�FY2�>O���[����o��+|�N����l�����Z�q|���c����
a����o�/�;
1�/m�� ���D?�z�RG�� 	*$�w�4��YtG�Acf��@l�^ �U.Zj�y�`�"2?��������l����!�U=w�����6�����)l"U���4_���a�Q�����H�v��x�����P�&�Jq��Z���/�#<A�0�0>��������7�/N��D��1���c���9h��
�������#����j.Zzs����r��;-��)�<���GB�j������H1!j�/T�/��#w�f��m�q",|��q_�B[�X{�X�����[CX�+���<�=U��h~	���Uk��F3���z	Q������'}qG����V�;���x��*���6
��������*��)xX]���lZ���*&�������O������uD�������b.G��	�c'	��u>
h�T����>�3Z�-4����j���:���� ~���W�rtq	_A9���t�K��@���1�z��\����+�#�u��L50_Z")H���D{�EU�����b�{��+l���[_
E��U"OW�� ���C �j�WI�s���Py����.T�Hf�!fl3D�6�����7�!��t�P4���Er���`��*��P�����uZ�b2�+�.�W�N"��4iJ������P�L�<$�
��J����\�^�k��#t�n������oO���7I<[�������B�L���oV���Y���~�~?Q��U<���Q`�� �����y�LR�/.��6�a���!��X��]W��*Q;�.oP�|���M�D"�r-�G�C1
�%V)�E$�����Bk�����Q�&�
��� �X���; ?�����=����0�e*�W����_��b0���E�h�m����]p�������_M������F��&����
]�A��z�
+D�/r���F-��
�����~7�������E�������4��1���Sk
��s�Th�"
��_�I:}���c2�`@l�2 ��Xp�!8�N_��Y��U�iH~5m jm!8pl��6\��7�;b��b�����������b�-���4Uu������K��f��0����	$O#~�������Uj��He��N3t��<�I�O5J�{+
_^���������L��:E�O�������k@f�H��Md�6��W��PQM�Ve�+::m&��������\��������� ���n�6�h=d3�.-�-��|��rG�7�m
��-�&6�vT�R�^����.-��z�j�a�^�%��P�k=B�������&�oE�����-H����k��$�/�������
�C�_o�r�g�d��
�?��ip����)�n���7
�D����W����x��<�bK���X�J����&��Q
��-��v���.�`J�X�~���j�S
U�v�#�7���Ku'$,:"�B���d��[��%���1�4'������[k���w	�hC��K>�V�����[�R��f8�r���'�2y�5~�J�W���@e��c��.�����8L�_7��Q,2-�Q��R\y�M����F��tl����~C�CNg��
{C���p����Tmc��(���X���1O���0��O��b��l*�ta4��E�N�F�c�/H���'�%X��gF�����1���^R����;<H`�B�� S�N�KK�tn����N��|�+��-~]MV&2�@�!J4T6"d���A1c��I��&%�
o��
7��,����h2�~��G���������5�T�L����C��7w�(�BV�O-�z�ys���Y��lk�A��V]
lkM	P���^]���h�T����h����\_Og�Y\qD�c^��4�t��E�U>?
Z�s�g��O}�|�8e�o��m��s�7�o���������I�?���M����8^�a����U���������� �L$-��<+�,��B"d��J�R�T��������D�����f�� P&6�
�I@��L4K�xd@Dw�Y�8}ey�@@�T�
:�^��L��K9K� pm��\u�����v�N@������v��-������
p�`+h��/^���/=��oj�h*�v�1��G�+��U�E��L-��������9?G��GJy��{�d�d4���'�tj����s�9�2�
X��\�d�
�XE��vW����F�K�|��}|���=���p�x[�����J�g���N�����x��f��Vt��4����9� ���L�G�~L�I"������D�Ho�	���D���'z��>x�s@�a���B�k���h�~8'��K��jh��7�T�4�"�����Y���Ts��.:ZO��.�Ao���S�������E}J������t~��X�*��#��U2�e��Q������I�U��]`�4Ec#�T[�J�`N�R�n6a��1�����>�<25H5d"C��%9R"���n���y2.�:�.lc�8�0�mj6��0��d:Q�y�^�>�ej��^�����!�;y������%��7���a2��Z�=�/��z�qA�`�����H1����62#z�Q-k�S&oIw�F��H��Ra�&zt�mt�_*�����4��8���O��i�a�	n�~���������
��Xw���k�dD���	K��s�<��3��n-��b�{-l��5,t����t3A��*���K�+�E���X��8�����EY���W�q�_E@f 8D~E����{Z�E��']r���i��*V��t6���*j��
 xy��qg�':XEH�%���J.*�F�JYK�����u?�XrS����x��E��g����3�`�0�N��	pC�C�����V��T�m�]�k��N��a�~Ui4�������
�X�������{pSG��x,Z����EZ���Ca��|�e�i �v���aZ��;�@��/-�f)J�d���;Nq)�9��������r�����GS�o�e��'Y#s��t�R��-A���_v]��~��YQ�����M��4n������d�1^��p��UR���;��3�Gn'������v������t��"�c�\K��pOqT ��9�D���f~N�Tm�YCaq�
+�z��F�jb���_@��f:8GB#��|�
<�6Y0��j~oN����
Y��BV��c�i������.�K_{wI�y	��:��e@F��`,)A�J�z���>;�L$/��F��KD$/_\b����A $�����������7������7sGn#���t�D�K5kJ�m�S����$w��r.[�/�_Z-/W3(4��-w�$2L�X���S��B|��A���~���t��/�r�y��C����QZ%���������]����CV8��&B1��n	���s�@������<��AI�s.�Kp_qH!s����������jg�����i�U{���h�����S4����D��Q�P��Y\<��7I����Fd�b\���N6�==iw^�~:9u��Y���[������_6-�0n�wR���%�����<M�(-�X.=�6��g�_�8��<�hv�
Vu��S�A��t�d''�+r9�`��pK���9?�.��p����i�F.����l������w'S����K.��B����F!��w���A�.|��\���?��m�����e����/[�����{Z���EOd�d�2������W�S�k���������.@���%Iw���c�����y;RUf������� ����!�d��4�����*�$���}3���B3�m��X�X�&�G����+N5�R����z�j(Vp�/v�}�
m6~�\Fi|,�bf\������Fe�L��yi�=�b;���Ht�XJ��� �/�F��=T9PxI3h��A�6�(�68�����is����;���	���L��o�!v9�ySE:��s��3�
��` n�� ���6x|��?���w�Y��4�o����MSG�l�8r3����z���FH��s��C����B�`����l~�)��I���o���'.�����CXOhw�!�1"{:�W����������cV��W��X���6�Ga&�5����)"O�x8*���1o�/��FD�e��[���FC�8k�S�Y����n3�nlm���K��u�{:9:��O,��(N���\����q����s�Q�K�':������}�wb}���S�H:�����@t+��z�W��A�������m�a�al3D6�w�����&���m���y��
��<����#����g����R���c�:Sm��
��A�%!�����
�l����|Bq���"Z���L��v��9�3m"������xC|E
��
��:g�(x����*�QBii�@�����D�N~��yA	�[���9�n��st�R���Wghw'�W9����v4�g���3��0���q��������
�0{��a�_���{9E�/<#�����>���S�|���%�H�toNHM�����#l��^�HZm���~��I�����������
��{�f3����Gos�t�|����������!��ic�{g]GH���;��76vx����9�_f����!�o�<�/�Y<�xL�B;��B��ZL��q9���BA�c�;'��*qV�ME��r�����7���m�������e���+R��2|P�
���p-LO�F�������=O6e1��hw"�������^Bu�����oG;�Z�Q�@����:�������9D����>6���`M�������4�#~��$.P�yKB5����������6w4��l��n��qY#���l���i2�Pe��yo<�xr}a�3^RcQ�z6���R`.�����Z������z5�F��7�M�9eS�\��<19�@_�F�3�`�~7n>�T������tD�[ ��8�U�\���B�y��:/�3���)����T����7I������8>�~<��+=�=������:�����G��^�^����F�X�-��p[`�y�K���t��?�n��(%����P4������ A����ac�5��]�7oE=EQ��+���Z8�����>�HpU����f���U��%c
f5'�������ifc�j5�%������x�!�o��D�lMDT��t6�99(�=y�D�2�N6�^0=���wg��]t����~�:8b2��^c�p����1X��J3�1��#}k���P�����\�xF��a��U�BN��	fJA���J]#$h�3���+���S�>��\�/xU�K
u����z���
�'_y#HQHgiBX���"E;�#I��2�14�x%��V�C ��yAO����W�A:���T���!�e:��5�7C���,a.����yY�����wes^W��;]	�^�+K������LR�R�I���s8�}��@��H�e$&�e�QU��et�0�<��J�`�e�QO;���>��"� <��:\VcP�@�vz�������^mC���6���#�m��{�cLz�	����\f�1�X��{UwY��[/A4��qD��i�}>�^q�������{o:/w�@�!e�a�'���&�+�o�F�#���]}�6��i�	�"������c���~pL�kH1�$j���
�*��Tm�S��{��.���|��Zz5
H�����G�-��,j�~+���&�2�8�+,�����of?�V���b��X�'�.:���h��l4����_�M����p��h�A����N�#���E1x�����m�����dt���	�4���V������P�:���&7�5gb��!���n�Z#+:��~R{�;�{���#T)|��pw�`�:Z��H��;�{�b�@��iG�|`�XF�eg�x�%���}��� o;��9��k��O�� )}�����.���a�;��`�eb�Ya��\�]V	�����+ ���c��C�y����P�
�/g�d��d�	������� ������XN�J<Q��?[C�4Z��9�R�^OE���0��QJr�����K��A��ZBo���G��	F���[�<UC���O!$��X�0���Vyl�+Fb��8�z3����:���&�Q����x����������A�!^}>�}���2�����K�ilP��UU����FA������*6�b:��"0-|8J�Z��3�'��E78��^B�n:�h��i<������D���%�xM�e{���lY���1F�Q��6�gG�S"�ZN��s��YVt����
�������8sP��:��� >���*}��������I����
�,�n��h�3��D��=h"�qHx��a�1����+D'��6.��F�	���K/�j#�t$�5�	��"d"���S'�W�e��3`��Sd�����������EC��}t��0D�p�I��e\����Rp4�I�B�;���a�T�
�9���y!��4,�$��$�!����O�tH�8�+���U�S
+}5e8N^�$���~j�ps�����#�I���H=�L=�u��<:��k�3��xu�@�����?��������E}}:Zz�1�����&���v_�������v��-FJ�:��A��D�*�
-��\`�%�i������J9
��1�����/��z�d��Iu� ��4Qy��V���q���E�'5
7�9�������0�V�`��!����;J�����(<TAX"M�c���2�v)t�@u���q�����\#��eiy��R�QEa4QOAH�w��v4�#I��p[�i_J4�`�����}���h]�G�V{��L�5�%~Bv
�����2&
�����[S�����H��[���� �p���D���j���A�o5-���7���z��Q��'�"���4
�L�,�:
��k��������{��s�Z�4�R��/*!d��-4�#�6]��m�����X���n����u��c%b�`�mLiU�>�o�J�����1QIih!I�8�LGC}�\�S� G	�Rs���	�zLQ���cH7N`�����~���8�+���k�,��~�(�c��dW�(j�l���% E���G������	�����sP��
�"�\�/O�2C���PY*T������8��#�U��D���<'���������
�P3��s$����U���TU{���������:$�4*���GH�V�)i6����*���$�-�Wj�!�T�����U��p3� ��w��!�������/���x�>*/�f�y�9�AJ�������j�?X@��'���`A�"���\<+��:�x���
���9J�x���c.��rDs��0�)�Fn�&���(_�����+G���9��*�;J	�_�T�lB��f��������N��;��<�B�%��Y��������_|�d�0?����o�W_��a�7�����^3+��^�K�T��J��w4V�4u���8?tn!�qnz����M�8����������!��SR��i�����Z��{^1�H�����hx�Hzz�+5@E�gkNM��b
�s������3&�g���3��4���4q
�����Cu�2)�^��<�K���<��"�<H�
CT~d'�)����=��m`a�y��]���j�v
���2�.�JSaWy�s��K�����th�W��#��#��O�P��[��q���n*����fG�p��f��%�IR��F�w6r��@0`�v�:�*���B��9� D�J�5�q����?dA3�1NS��� P��*�zO�G�1��+:�����s�^	��R�hz�
��D�ZI����x6Rr��]L��Zo����j�a�"E�v1�*e�#<����e3��	�"����a�"i�#�L"B2���a�x���@0���1jM���^Y_2O�b�����������G�d�jV��E����(��c����Ai�g�C����J2���W���@����r�9=��M��;�~,r�,��=�/��*���~B��4tS�,��6�S_����)mKVv�����['���0�|y���|�����P)���*�����+������Hp*���R*�l)�7�P�
�A��{�al�����A�z�65����()���7y4.����Q$W�a�K?@���E���x���E�����W@o��(���!�C�h�����D�	"�6B_s��uG���4R:]_t���;�VtZB�(�;����kW��/]c�,;�d��l�:'5��K�����]��Slp�mqWB;�eq�4I-�����%3�t3L�t���jQ�l��L�����G�O�I���+�+���q��*�y��u
.u�+$ 0�G�|�W��^�,reRxa�UH�Q�S��ET��	-�������+�ZVp��*sQ��T�\g-"=����
�I�M<�(����:������qG��%�{^5�X�����	�P
"�]��D�c��"R�w�Jc�p��]���x��9���L�V�����%c*�8��E�b�d�L:�*M��]ZJ[�:�.���� �E�`X/�*�8�n��J��GO�����H��]�h���6�d7��$ZT5%o��~+_A��u��u����f���1j*�H���B�[E�{F�D��5����������U<�/�f�o�3�E
�D`B+�u�s�����&1=�6B=AG�7�b4h#Q�����s���exTj�.Rj��^���)x#W��=
�d��|��h1R1&&<Z�z���IjQ��-�3z�[��n��L��zf+m�]
�,z�+Fg���nXj�����?�^�Y�uYMH�,�"��/mO����sU�o�r�������	��Q,0�u�j:m/�b���m��h@c�����:�d����������
�'�V��]�pq+��]_2p9�cmU(��t���l�)���t�RE�mD�v����*���
p����j�k�����}�82�DF�������h�3����wyr1bO��W�)�$NMS���z��X�������V�w���^BD���XD
�I������lU�b�T��������"�����g���
t)�E��Pq-��\�_iA��XG��Wm ��7ah*�^��lk�/n���E�����M�s*������n^B<����`����}w��*�NH����*���"O(!��x����n��V� X���`/�"KHR����T�g��_`��*x��H/��.Rf�wf���������Y�JO_���#������Q���Z	����	z�g�C��^,d����rG�+�x��g�j��V�����G��D<"3]HG�9�U���he�������[���VQ��n�QV��v�i	�O���q�s2Lq����]+*h����(QQ�[�1�-Q�U�b��'9U�+�8&8:$�WC�
Q����B��S2W��uhz%M��:�qjM^G��9j�r��^���Vg�l7�2&�L���<�+N��xT7y��
R��w�avP$�l]�f)T��^�TLm����:���"M}u5w!�
�Pp�)_�� �G���Co_x�D���5�����A��3B*CDCS'G��/.;��ov_��:Mp��/�����]�g����_���d���"Yz��$RT{*���x���-t@��8�c��5�����Z��Q���G+S��#>����Y�ch�-��VY}�����+"�Y+�H���Tl�������H�H�M����$���{
*n0���f"`�5��Z��sl��4���\���� 0vE<E;
�<��d�;������h���D���j�1��}�$�+X��0��I���k���`�>�����L�����%tP�*���
���:��U����`�����'�wP��#e/������+���Q���5
�D*�mR9�Rh+���^b��_��d�F�yk�m�{��B5j�F�v���
��}�>b�������F�
|Y��~l���k�#�#��E��ez�Qo8d�C�U�N|<5�Ap��NePus}��'����:h����nA}ZK�xW��K<�A��C�N��2�+< ��Q!�M�X��,�=F��l!��F��JX��h�K��4����r�HT�5hzx6H?5a���r@����I������okd��;��if��v��h5��&�3��SASc��(62�����g�}u~+H���$�{-�i���!��ht��n���(s��F�k��V��Q�Q�.�����]�v���.h!��	�PF�b
kifE����4��C�����,����,���3��������U��KA����D����V����i�^fX0���)�al����Q�����Z�{Z�������_���[��vi����!���{eAO���"3�ZZ�@��k 5h�)qM6]�+q�S��u�.�U;?3��f{�bk�W���:�/:����{���l/p��,z���{���8	��:��CQ�����|���[P��i����/O��6��Qd
��o��5z�{U8���L�%��Ql���O����x�MX(�*Y�@�� �v*eR#�%C�/+���[���kX��^�f�"��2[S�g���p���[����Hp���"�m4q�����5���,|���k�����8����R���U�#� ���Z��S�����`�F���Q�ED��t�gN�����zs�G��/��AM���HGP��C����1�N�����&6������:��54�������F�/f^*zQ��G�1��k�+�2�����~P���5iG	]H����87��(&L����D��6z�3�Lh�V�z�6�R��Q����
<`e&"@�s-h#�q<e8��s��0��o��"�a�nl�UStV��.g�{d(����|OLz�X�CJ
V>4h�����VR�M�RvY��Cx��QF���;���#���u$����p�(�8!S!+�
%�~���G#��E�	?���x��� ��5�bAm,���kj��S4y��c�&b|
1����`�mAr�!?gs>�k��1�����f��	Fs�Zo�i��.�k^('�1)�$t$�O:Nf�j8�}M���)�������V]8�I�����E���Z'ga�C�&��}���!�.��>�f��Y~R�#~�������z���"���F:u����o����>>M
��M�����u5m�!$E4���������3�Z��Yh��k"sMfq��H�:�.���|��GxH�(��${����[Il��B�m��%�d<��S��*��nf�[}/��)}L��#81�|-cm���m����	�k�c�,��sw��|&*M�M��Z�����R.��P�p�	a�%FK���D��
dz]��k��0���#��S��f�8���j4��z3�#q<���K��@����Eto�-'�q�ZC�-W��m�,0M������w�K�=Q�ve:�G6��vFw��T���$F�G��5����}�S�p���K.���.k��+]����C�;U�9\��F�2M������d].�SXS,�#�.��* �����������c��9y)�qu=����9�\���}sU�0����r'���\N?P�������'����r���������?
�;�)��	,��lu����	���a� ��*49)�<���Z�Qr#��<�Mu�)W��K|��=�\�9s�`R;�.��*b���5���L�,rRU/��/v�����?����P�9��/'�s)���f����1��������X��4��"�N�z�	v��C��������]�	���A&/����b��Z0p;��-���+�I�t�C;
���\��Uz ,V�~�Hw��5�w��0�G
2�x�ad��+h#xwl��5N�I����nU�x���>=i�:��*�'��[��<��P8����B������s*����%�4��o00IG�_�b]�F�� vKiI��]��i���
�A�����r�����.��OKHP{	�N����r0t���WD��J�0C/���
WK�3��-��K`L��i�:f>������
���x��SYO�7�t��q+rYe�4��0�-�.������&a�b�����/UR�Syo�~��f���W4��
AU���b����pI�n��`*7���:�j�� ?�fH�b
`�����������kIS�r��
���E�+��-�I~h�����h5d#X�e23>���������"�g�C��a	,� n
�_�V�B�:���(z��(�g��o�G�K���[\�
���O'_o�&�����i����D`�>
K�,R�HFA���[�6&O��
�lCZZU�4�e���%�5dz9+���4F�s��S���-�i.$B��:�"����|�xp��0�x�����������99������l��e�
��a���S����z�>�X�����Y��������ujY�0�TEf_X7�u��d&�J��N�=���DCW�@y��/����=2#_}N�X�>�s-X��s�P�Y�&7W�l4��|�YUAU�&5��3�����7�*�G`2��8�*��Y�):�*�u���9�;���mR��W��$��2"��#�LE��UxT����Y�g��
w�~���9���	��r�wK�2-�.�"4��en��2������m��.��������n�0�*6�o��V�6�&���"�~e�"�����rR��2K������E�C3����V����lM����{?�2����f���_��t���
A�Ej��a.|V����PJ�9�Y�����k3���)������Xxx��6�|�������ow�y�DR����$���T��I/��2���?v~����M9zFf`��U��FNaSN����qg,w�����He�/����6f�����Y�E���*�4��K�r;��y��]v�v�T5O������T?o��k�N��[:Y���r}��F��*�����C��_uW�PaU�����C��ED�}73�r�����;��m���w����D������t�m�!Rgg�R�������M�������@�F���J�����M��O�\�s���R��#� *hS�&�b�zg�{{95E�G���NL�N����Xa"����~D�0G�
"AP>:�W�yz��JYAM���%D�L���*'������j,�����T����4��4W�75�������	T���B~��s�R]v��),o~����A���C���6���.��V`���I��<��O��ff2���4��������z�q�uOZ��z/�i[xx�a���6Iz-����t�x�g�)��%�Vx���lu��8N����m��(�����7>8�/��R*)�����j�?�oi����!�=[����F"�>/���\`C*5��	�\�Z,���m>�?k7k�����P�vZ*]zjI
U�}���0�jz�^~�[%�&�['���K�U��B�l��U�aBa���S�{E��T-��,��-�|�"E
,�Q����8�4�Z�G�4G�xF���$k��`
�].Jb���5�}@1K������QC�b�K���K�$e!v���G�a���XIni!�����_��t����!���������b2�$���~o�>����F��XD��:F�a�)��w�������������~co{c'���oon>X]]-������R}��+��m��������������Y|@Q�[��j�3����,�=&q.bUg�����l���|��Vs~�R����gX���xf��
$KJ�R��p��P-��=�v,-jBR�`+by
��&���l-�qm����t-��������/.��k"9��8�
Dq���������Qo�O��)�,��Q+��677���{�I�`��r��~�.b��`���7��[F���)���C�[�?)��d4����%�<K[�<.I�f�mfH����0����kk��q=��{�H�����4��ZG��>��v�������S���6�1����u-z���+b~
��TUTa��G�e�EM���N���b ������%6|r��^��U���
wl��?�����y��V�IpkdI��M�5��������9�=ZF�K�Q�4���}��}rv�:Vk�-
D�]
&�=��Ev��(jD��1.56�\5n����,�������u���I�<�>��LJ|z1�"Z�<@��P7��#��q���f>'Oz����K���Z�����x}{kskgmm�|g{s{oo;g�e����Y5�6�6j;
�D�g4�o��|�r}�������,�� ��|4I���W��h��+~!�f_'����8X�fT�2�"Nko���U�o�v��V�%
,�����qw
6=#�����*���I};:� �����E�N�tA$u����Cov��0x�JiBD��lM���5����������q�{����_���E������pSP%��z}s+n�4�kk�������nc�������W�j��[���_�y'��W3���t�+��QW�Y<�v����t���Y����I?�*�����nsZcJ����zMb,�����O�u�92|�p������+�<������5�H��I��(�Ioo�l�6����m-U�����.(/p���L������6l	5�n��������(�,QI�����=��]��6{���`!�n�]K��{��CtRN-����!6�����S��= *]��kc$�|�s;U[���I&A)��z��=�?���m+�4�����G��ct����N,��G����?��P4b~��D���s;�iM-E�I,T���^�$����1lT���aU5C����Du�wQ������k��H�<w�W��`������5������9�6��/��_�*_=���]Q��x����v��9�\��A{�-6�/t�c�T���E)�?e�_L�"���^`8Tj��+��4$RZ�y�=Q�jHPXq|��cao���I�L47����|{���x�������+C4��<r�U�P�������w�5��4�_�Y�y-���R�<��%���0��;�E)20��h����O�7A��]����Q���'����x�W#�P�F�Q������zm���Je��9�W��V��+��
D��Dk�q�!1�ta@���6����
@��5V����:�/�� U���Pu��`�h���c�*��`���wP#���.���B��z�n_�5$��~�����xbpD|���j���.�I�����PK��U��������y$�)�a����&��C��Q�~t�:��|����RC_q�3l�5�-zzW�O�g�:��P;����3�����@����@
g�}&�7x���	�N��	�6�Gk��`u	8O�BQ��S!��d}���h8�f�8��e�N������7���NJ����*e��X��o��{��Q�=�|U���|��vL��1�/uz����z��Y�x-'�Z�i��s��s����c�.f���)J2�B�&�
&�@Mc
�[������I�W����8������`�m��4:����w�3=���Q'T!$���7S �b���t���1�6����)U���Q�Io������|����i�f��
���������x���Y�VP�{��V����=�wH���M#��}V�r�EK�B�2q���7������C�@]�S��	NM��Y���cSk�`+��2�U��o������M��d�;82'n%��	a��/�-����+��@0���+M����rg�Y���	g���3�������?��e�h>����������0��ZUX�)Z@8�r��
D����t�=�(=;��v.^��U��H
���udT����Y<��i!�YD�K����Z�����w� ��;�r���aF�;�)5�_}�4	�������1�r����u�J,b^A��N���as�����M?�����\P��db��������9���b��_��J�%( �(*��*��}<�HT5XU`��
u6�+<��l�".�f�~h���
:�&�������{7��� ���@�������K�0x��Q�C�1o��X=s~�lz��g*�n{��4��<��6
�W�@��+����C�J�7��
�F�srx��-��_�sh��o��[�<��aVs���	d��&�����k�B�~��==;���h��:��o0�*�@��'���A8C����Mn)�!�,� Hkw��t�UT�7E8pg,qvEU�U��Ja�����W].bn�r�s�TN`[9��.^}~>��Z����}�m��y�="��fu���[�4eO,����q���"5�J�����RA#�D�WDC�t����c�> zk����\����9"����(��`:���D�$�oO�b�>\��Y%��5_4�
�����T���3�y���!�d�������J���2�L�C~@\�����
>t�Ub���������
�������x�'��N��B�g�b�[�����F?�E���U}9�����c�A��V��J�\-��N�Y�H�� �E��:�V���_�,�R� I,]e�������)��bR)x�)Y�4��7�L}�T2Jr
��#-{�@6y$s ��Ee��/(a����z���e�D(�
4�����r���z��QQes�I6v������[�a��� KT�Z �#�f���>�����zOf�s`0�R�����=
M�������|4m��9�w��kuEt�66j�F�Y(|�p�����;���t������;Y���q3i��@PFU�L�o�����h�oQ0}�Y��@	����*���2^2��L�V#�ZS�KK8�o#}R�$]*�`C�����I���}+^���o&�
dMT�W#n'a�����bJ�x����e?������^���X];�'�;��@����D����eZjCn�^�\m�%��Ms�~�y���o��>%�g�'^��^�@/��s�����6�dpu-;��7k~��Vem6V�m2RGH��TO�Cly4���P�����s�����&t_%���H=PL{M�D���W�/k�dp�O��%7�q���_����h�1w82S����Ut1��@9m%��c�f��J-l4����q
��h�!~ ��Od�y�|�N��!>�SSj[��t����^L��.ZL��0V�8���s�u�Y�[W��������U�G��7��cV����|z3a���E`jm��"�A����m$oT����I��)�I����x��{Q�p,.�~���� |O��/Go.%cc>R5V��B}�yU��PG�R���g]����C�����q3�
�L�[dTD�d�:�������ycz���J�a�%=������B6XBk��d�G��c��
K�F���� F�:;�����L+���!t
�qz~��N�?��B,�MiO�S�E*�������#�'$��}����k�)��N��/�����������U�t�^T@�++�'|��!�3�Z���D�\���y���a�C��
�
&�C2��#;6)����A}}{�,�������2�Tt�,W���m����U�&J!�+r��|���2)�#nP�.jG�j6,N��dyB
������	�3n��T�u��#5G���N*�EV��U/�����"�z}����0���[�?���{�uS
�\���	�+=j�)�9%M?F�J�
Z0�=P[
�jH<�*�����Z���!�b�
a�
�a+�$���P��y�I�C���pH)��W���T����%�
(�i�������rL�z�0��F`t�=_5O���zc�do�"B����.W����Mqc�����E�2�G����'u������x(F�
V	�z|tg=���(���]8Td�&S��c6H�.�����-i5o(�����b���h�6��+$!�pf��&�����d���`��p������A��}����,\�}>�+'�`xU���=������1w�hT(A����jd��=��&z���;��fcQ�W�_�
M���Rh�c�|�f6���\�4���E����w�������bt�Q��������Q����_���p���V|������U|2wC�,O7n.���T$I�g����s��IWIM0�4*A��L4��g����tD�@{�����y��_wV�G������	�;
Np��W�9
	���;\���t���$�2��\��x5^������P�s����r^Q��B�S=�n�J���3~S{���}��uK��1������U����|��JH%1����!`��� GGI�	
��
O����p�(.L���hbv>%�y��G����8T��:7��^�=�#�
ayD@{D0��p�$�
���RVC{��)oCj��Q����=�������Z��:U���/@�(p���������o����2��1��HAz�Y4R"Q_W���l�J�G!�_�AjC�����#WkP0{^Z��w~�K�/!�
���w2��]���X�-$������<��]�gwW�Gb�Yp��`�T�P����-���Y�l	x�e�
]�+X�N�\�p��t�;����t�p��|b.��(���(�y��Y��6��ph��t�
��PL���pc���EOh��C�R����=
Z����L�	�=$'y54�E��\��P����|g�kA�����5��`�Y	����.�1n4j�������a��7#���������&�X� G�
�82�>C��bhVR
���k)���H��S������
%���:<���9�i��L��R��<(w�����e}]1���ol+�g#����'�ef���}V;�a�P��S����<���������,c��]���,{�"]�E���;�(qo�rt�������)���3��_t�h��#��E.����K�#��!��.����������_��(��O�0E�:H2)���JQ,:F���F�{����5N��8�;��9w�<�%o_��i��f�i'��
����[���m
l�\��d��%
�o\$}k��]�d�������W"i
G�'���
�p7����6�O��I[�����O��+I�Ds�f��WVDMr���m�},G���|k�W-���Xe&����X��k��EU,���t�0��1�d:+��Xb%�5�w>��~�l�#�������T
���]�����p�����8�t��@$j ����/G�8�TBko���b�c=f�Y����$F65�
�Y�VLjd�a��',!?p;���NPw|>�'\�
��: B<��
��j�hP=����J��o���??�FF)�/��5#K�gA�h�9���52����%f����4&�S�%$��R��7��$��{���h��<E<5�,�{W��p�B^;`|?��q��]	�z�)=��\�5��=���)����C�mN��m�98h��f�1��������I��p�jLzqRN�#��F���?g���%�����%��K���R��`p��V��["�C�)V�^�o`������s�dhxI����jgk��1t��;]=W���%J?	�A���g���Z����x�;�;�5$����0������c�mnu���������P��d���c:��X�m'sW8[�ZC�u���v������j�6\-����L�!^}NA�uZ$*���|)~.����#`���-��z�s�}����p�i��w���w}�zX�w���{���a����1��n���/��#�a�Y������o:�����;��=���k��B��K#��!��`c5���o	���&&v���D���N�c�
H�ae�%A�Mh����z3���h��������*x�������]�'t�#��8�1i��`�����d/�46���'{�Ht�_�����D+&�{f+�P;kkk���&���I�:�����~�,��E*�Y8���I�?�K��e�����g���]}��wo�[��
����H^����\z;�P[:��h2����%�-�1����:@����w;`c�K%M�NFbF���O�k'u9��T>���1�
��0�1�z�����f�^1�i�-�����<9"'��7��K���RVH�
��%���Y�G���FpH�
p\&��(zH��R���%����KF@���d�hq�t��������T��~%��Q��
�Z#�
���(�:����+/�\?#�\(����������b�-@�Z8����n���(7�)
���g��O%U�'��h����?��>��A�)��^1IUG�H���X�
l�$���a�JR���4������n9�_�]#�=�������z��:�fNL�H��mn��4���*�v)��
�H�`��)����9k�"9%+c^��Rt>��0J����V4toP
��[����
Mh�O���gE�|3In�A��5+�!��Wq�}�
.���������PLR����6y)l��E�n'b�9�����~��r�+�
��G���T�@12��^5d]���{3�a�r�v����U���#U���������3���^�J�W���?�����CS�1p3�Xaw���[��fCbE�:�b�'�	�9g� �z9��O���:��������W�`��X����mJ������E�R5��&��0#��_9���9Zf�v�iR�8���A���:&��Ru|�������F�����J������s�u��c���K����K!sx��x�5�q�W�k1�._�����7���(+�t�U����E�E�UK��D:�tu'����r�j�#��H*B���z�`�����`=A[�gD������d~�X���WT���2�.�����������y/�w�7�KQ�+'��(�,�l�����E�&z��~�W�?4SmH�x Yb����d�)~gE������/26P�&36���4�EF��n������d_d�}�Q6��*)��^c������/����4��-�����76)T�N��.�����
�(3eG���7�k�`�Q�o�/c������-O�Rag�F��������e���/d6�����a��a�~}���0��_dz��]�����{����w7`���J*�F��+-���5�Z�y����s���:�bG�>�� B%)��g�&���0���{~5�8�{�=���B�hG5�Eg`�w'F�H�W�i�D�K����X�����}�u����h�>�.i�/���S��N�3����q�y|�cxt��K��,s���"e�^|R��$��}X����Q��m �n�����h[���,��c1J�6���6����)3T����������1O6
���9����)}bX����a��>����G�x'���[5�������_���Nd�0��I��A���<�j����.�A�O�u�D\��7�������FJ��j�w
z��l�9l�P�0�=s�ql���������������>J?�����1������\+���T[��Z����^V�h>������1���t�/���H��)[lN@l�R
�-2��oY���GK������w��E67������&�hv6>�I5����D��-"=|U������tA������Zc�<��`��W2�X�� R��/����t��s��	��~QX��x��8����������u���LM���z�Y:�s("@�8���c{�v���cR:�-���?�	d9���q��1:���^�������B���(0�������wn��z}I{��1����1�S ���-�_-������!���:�w(�R}�^�{���GGV�RA�n&c�K��f8�W�z`��������l� �X]���z9���?i���iy.���IZ[����(��]��3}|�.�}�}S�o�>h��Tl���L~Xc,V�������� ���>.���b^�^��
M��`����#�>u���2����S��Xx��m�[��L�w��9���/	�[f�Qz�&�x��=+Pohw�]C���6SZ.�.q�����F��h4�j���;O{����
_]�&�d�v����5��D�������lOI0D2=�/�{��&T�'u�gvC�4�UM_�K|�?V����GE"����I����e���6�Q���Q�=R���k��@��/N�#gC�]�F� �xr���w���x6�v���`���Y��z3��+!F!�R�D���Qo&�B�����0��S�+g''�n��m���UT������y�$�*LD���\����'��� �����txs]!�����y�^�4J��B�n�N����o�2lw��h����1�>:����Q9���K��^a�I�v�������U4:�O�����g�L\�y���������N/&��3�����������D���������q���j$��-�����]w�w��5Wb��0����Z[�m��;����fil�X����&�h3������2\!����`z�^J"b3eb�����/d���0j)�������^����(��X�Pk����w���{t~�-1�$�1�J����kie��iTfb1O����3!K������CJ�$�5]%���8�6�+��{��Xl Q^���I�����f���hA����\�G����f`rQ��\&Q�������KK�`{L��n..r�,Y	�����$�H��f����f��iv6��seGG)�uj�o|�Y6IR1��:��v������X{<��SW�9(,r?��2w���B�����m���l��h�z�c���tF�Ch��������|�es=���`�,�x�rw"�"
�"%��e/9��S�n�[d���U�P5�a��*��5��'�JV�!�3w��Z(!>����#���X>u���%70�!�~b��E�z)���a��J������u��P3g�P��^/�`g���!9�Y��������+{�p�1;�}�	��������,4�����|��< ���
JWJ4>�E��p�Nr��?�F��������W}hyU���f�~2��:��CT�W�r��0H
B���������|{������7�;�;[e�A�V;���`�Q���N����X�A������)��m��O�C�8��b,��t�a|=���}�@��\���h�����<��5����t���������g���r�]�}����u�O�j���rg�
������D����>0Y�a�pD-��5hS)��1\"=��������D
E�����d�g���lH�2*��u��j���]�����	3��oM�F�?$��w��}"%2?������&]�	�D �������A1�
�q5j*���x�S(Us3�FW�K�,�����Xz�|�(��$�8���:����(A$������uh��������u�>�����P5b��w*+�E
-�F���K?����;���iEZ+5�q����p*R���;w�:��D�2�	{��|II�-v��"�����$���2�����;S����0EoU�I���D�kPq�	}>p\���g�4�H��~�
�
!T��&�xU�PL���eg{H���D_�������#�M+���n�-�y�{	�n�������"���m|]^��$�P�vH-�|������e
1PkWB;ms9��QYomol��zk{w���#R�OgW�6�"�$n�b���Q��w���h1�j��N�L
�P�����"�j��D�l�E������"H*N��W��~�t�Q2?�_���bE�O�v/M���PK���{����0w�k4�6���������`�+��$�Mqp\
U3;��!�"/���U�0��(���3�M�P�%D%O��K� ��h��o4I�W��F���IVN
u�
��s���f��kE���k����ltM���zUqR:���}��?�Okl�-��������O�7�SD+L�4{�5�X�6���!���(���b�P[E�t����t�)i������L?��0B$>4!�}3����P�~�}C��?k~�A�5d|��!���7�]s�@�t
��������p�co��U�"F��U�	���(!��Co65	V��`��F����������z��$�,
�bxf:<R�h����zb����O���!�z
/�9����GTX|<����3�.�����3��G��5�h�}��aq`��}��zT���?>��Qg^"S�L �\���n:X��P������
�nz��g����8>����5]\�^/�`
j�$��tu��Ug�C��Zd��J�J���{�i���m��Fgs�y��y<{��)eDm����M�����(�� �<�;S�c�#��> C�p�vD�=I����������P��Dy�qA�&|����,"
�\�@mb%(�3���ve������u+��A]A�
�R9�83�["QX�N�l��*�h&�t��}I/e���z+��p�����e5J�<���u=�FR�4|
���:�d7�CApp��������D��O���$��8EK
���g�����F;����+wW���$��K:�V��g��S���Nj�-�S���txz��V��+�Y�)��v2�����������"�A�cO��%��xC�Iqd�n���?4���d�[����3���+�'Hu	����5�d\��H��v3��)���3��z�=^�[e�,���MQew��U��% ��d�s��T�Z�w�q��"����o�'��J���A�)B��Y�O���N���?�*(�������G�S�
�����~7d0��;���=
�<)�1O0�g����L���M���R��B��g�����uR�\�&	������	�1Tq�P-jO���H������wg'o^}g�e	����B�&nG%��aG�,�ta=��Oo&�d
y����f�[O�LZ3��]x�i���W�c���w���|��Hhgr���8��������`i
�t���hC�5�q4������4s�_O�gli�XG =3UO�F]R�t�yE7��s�E��u�qr�<��dy�JVm�c����B��q�
����}|_��'tp�����
�WD1��Zs		$�����5dn�J�P�7���dD����x�qXq��#���Y���)U�t������;y&���L8y�KR/B�q��dn@=���S��h��n�O��~�;�_��S��<�G�P�7Ff�E����$	2;�������_"�\��U����8)��|��k�:��e��X��*��I410�c:�6�:C����
R��/k�V'~kTj}<���U��	�&HSU�k�Y5e���E��N���F �P�o�F������7T�y��	�����G�?�Y��oK��������m�������M?[����%.*��68���������������v?�;�-r[��+se���w�$��vFF�j7��\��p:C�����N����*�5"�����;��cG+$Ij��xv�*�F�G�D�KC94���@���p�s����
&%d��=wS��Jn�-d��a��D�zjt�(:9�o��
O�}"=�Y��P������g���>0��b���aP4y����\W��`uw�#odo���,c+k�c
�Z��;�0|g���5�����r:��h�&���n'�����TQ2z�
n�u'�:#�c2$��)��
.�T��prsU�E�WC���M�L6$q��.Z	�b]���sF��n�v�����g����S�G����v���B����%+�$�����OV��Wx
A�,�	R	l����^r�Q���9-;iC.�nE�P�k�}$p6,�I�I�h�v�MB����t�&
u�R��%���K%y�k�T�o�^K�H���S7�vK��D��bK�w��!
a���:�n��T65��8�8e�z�]��_c�R^��eV>\A5e�������bG���Y�{�$^���8:�J#d�����a�;�,�!m:4�'��3o�E8���!��Y��m������@]
X�*���66��ecs'F%�.����,��:�������������ocn��v
�������	r@�q����q��ir!T���}O�.��b��V���l�=W_����z�Uz��<6��osg3�d���]3�~|S��&���z���j�����5��5!sr^
��������������g5�W��%����x��[Et`��Y6����L/�
�I7`�V�6�d��������K�5�(�-�}��>�d��Hb2���/��$$hC�6����RJ�������E\���z���+���,��a�2����RL����y��'�H�c�M�WX�Fl�7X�p�`��_X��/���5�j��P��� �S�!�	���=	jg��
��t����������@t*�o<���2t��E����{-e�w(mwe���%�X��$J.�7�!�:���K����Ze�{�G��G�K�F#��U�<����X�g�z�l����{��*���wF��,n��f��
�!�nP������0��V�X{��T��R8�U>���u�J�!�<�[���FhA��qT�Vt�BC�A'V|�7y�B�
�<q�����;L`�������E����.�.��/]w4��Oi��H�������H�t�<B<3�E62G���������=���Ii��-#�/iSx�nLv0��C��	�Q����x ���Vm�`�o��7��)���t^�F!�:�����
�t�,��h�V�8}��_Bm�@G���Z���o�����o�~�RsW�-�U}<r#�#�a����6��]������������jTM�R��o��/[�Ma �=@���9'����]�����f<6dNp�U������O����f3�E�%���r�|�����[	/���"����M�^������X�`Y������}��#�U��uc��F\��o�4VL��-�l��b��}����
�/�����#wo0�x���k�����x���xD��+�����`T�X�2z����J�Q
�jO[��Mb�B��B���:6�#��d`
[J{��|@��>��q��f��$c6@�V�H�V�N�hB�M:�!�cS�Y�~~��1��_X�,�(� �h�!��t�;0�u�����)��	cH���c�%#�M�lygo��6�k�MB>�X�\������N�B������f�]{[`mR����a�5nZ����|�_�-���6F����o��tz�L����
(��+{�27��"l���5vp��\�xSMOX^�	��_�E�Gf���:`��m���-��z��^��$�J�tH���i����"!��[|���>�9<����A��	N���.�f�G�4p���4�H�Z�A:\�cT��F!e4�yC��@�X7��v�����������~��<���'�Go-K����b����V�fg_aa-.<���"��^n�����)�)�]]���5��c�o�Rg�`����0����)f�'0���������B/�9>89>l��o�H�����b�k4����`K�V����:#��.����0�N��>��6�
	�"H�72�B~�E��(�"� ���\%�t$$�I6��Z���917�{8��i�
����JIB�O����w��j7���Q��V��:%�Op�������y�V��<�e�������9�I<9�7s
�e���"0�e��c��]�����i�,�1��:�pm��2�g:���"���o�4�k�n���Ho��B��[	F����$�����NY��<��H+���@1�r���7���/|����*���k�����dd����$��<5@1�5�(����]JLE�Yi��*f���_I���w��LA��A�r��,�Y(
�=k��M��y��Yh9L���[N�Sf�V�K��f�����F�^ur�	>M��~�KDxgp�kA�hC��P�E��{���\#�X�i����A�<\e�XGJ��-� �g�@������c��o^7�Z���bR��jw�[	��VpjtM��'���/�h�dG�_��n��^����0uA�Yag_6/��P��N����
��v���YBk�����nOp�����������=>��_��g:�{��j#o���lM+�>���m� ���>s*)�C����j���i�����SK���erm�8�X:n�Y�dl^�G�	J��9�c�a�"���� pN��l$���$�<��H�
C�w:���4��A��c(��^�Q�Bx�;�v�����ws�������d�3���3d�9Q��[T�U��t���<J���L���Z�Z7<S|N,�{�z�N��n�)������\6����,-���htA��������S��iv3��W�����K����vc��{kk����5��5J[�m��.�z�=a�'�x��8����L�E��h7����$�����i������m�������<�t��9Z.n��6�6��:>h_��`��)���@��P��1��5q�,��{�:�L��=����h:�:&����92��}�
���1��S��������4������1|��.3{��������2B�N!����,+�Dp+2��!h�9��B��d�0�����"��%���y{��i\��3���y�O�Pr��&�	%�7�#�C�~z�;D��mD�=7�	���aw!\6���]_�H+bP��Ug���������+��IWm��5��a�����������([!��`��+z������1%���)�����DpDt�z��LQ�jU�s��hr	��070�r�������a�����8YEK��W@���k�YV0�����V��!����l�O������<�]�)`�wz��t��Q�<�hT�F`�� `S-�c�]v�}H�v^��Q^�����~D�=���]+�N����>���*R�X<9�����W�#�|S����������]�I%m���%�*���"�d�r=�������j,�:]�S��NU>��A70a����l)���B�����VE�t�����_8����<�������lWx?�M'N�r�/H��?>T����yh���8��������]T���d&H�&K9�w��>&�/8�D��.�$N4��P������c]��O�\A�{�!�QN�����T`�5����Cp��s��/��M��|�-?
�/W�[�f�!Z�����2��V������&;��#�����G<Iw@�����A5������ Nq���P�b����o!�@,�}C+�"}�--�F�:B��^d����`��8������f�-AbF����j.���������]r�X	����2���-E�YJCN��2��\�Q��cz��8jE�*�>�O����}E�/��u��������p�i<U�I^�(?G��#*"���dY\J���H�>����r��~��N��T+��V�t^���;�/j,%^�h�
�����Z^)5?���a��U��d��v��@ZU+�(g���Q�����Vq�~l
|���=p�	���o�L�z=Tt�y���(�O]�XP�.�!�� �/�p�������<���-Wo�����9�a�x�����V��u}P�����zO,A�[:�m
�q�~����/{F,����c��P��ys�������K�/4$��S&��R���Y�\O'�m������C���&���e�z�(�%?���7�2��^�M�5���i����9{���_����7����x��a2?���gLkP����\�T#=Z�������u�������j���;A�������k���)�x�Ws��+{x��Z�E��{S�I"^4����ur����h_�ME��=)e��-p�)��&��	RK�lX�,T��2r
��5&?5qy���?����Z.M�}V4�N�4�"�>Jo
,
>A^�����kX�V�k��%9�z�n�@G�%���b�3gt�6�+������?���hNj��d'�[���oN:���w�/�������-1L��`�����X8A�
y�[b���~�2�Z|Ywdr%�C����k���M;:��N��TG�co��������=(@�KJJ$�	��?[.w}B�z��K�"��rh$5����K�+o|I������	X�rY
j��j�W�P3�t� E���W
K���&�UA]�V��V�����W�b���}B��i�r�qYmwG�Z�	���&U��'Kw�����&[.�`�%�������	��t�Y�k���2��,�����RF~��P8zJ�������-u"F�7���Z�NV�)���$	�'\vsF�,x���&��Q����h�<�~%t��
-�4�/�4��M/d5�9L����*�d��������K�<�wYF/d����$6-���^V��NBB�0w-����P��s�N��m�����T%�)X���1sI�ll}U����-e@N5��3�Rz��.2��,Fx@�m���J�c{����R5F]���B�.��4��RJ��^aK
�����eE���(��I�idw$�w��r�
�����S��(QXGM�|�}Jl��r�J���MO��c�_�m��V�����I4�N�']���o�/+��^�&�{���?m����t�eY������
�P"��`�"�}
�<�[�|�u!����	���'���^��������������Z��W��"�6
����$�aaZ���L6���rC���^?�'��j7��*X��AGa��0�7aQ��W��R�K`�_���Pa��JK���W����+V+9(JjH������������LKqbj�������Hr��p]3�|U���"7�:�T=���^#52��~:9��r�B�����+�%5$�F��V*dR���iW���ehM4wia�Z�����C�5���3�o�%���%i����Z���-/nJJ6�vX�)lDH_�6H�*9�I��5��LC4B%��q�X���5�/�I7���\;���:�-P���k�{��d0_M*�7�	b�6W�j���[�R��S}���Q�������T������F
Lw�x���U���M�����{�zJ�
�HVV,sSZb�Ee��jt��U��1�@2=1��N��e<����J��Z��T���~�QW0�M?��F�Io�����J`h4N�;��Z���s�F+R�2���YA�t2��.���g�|�}��F�����a�%�53��2$o��S+B���H�+���Y��k��/�q��3�c��qts�V�?����b9w����������f9���0���%�;����{��k��d(�f�1�T�{��t50+�o���tDM�`i�I`�V��@����"L��)��a������Lo�H������H.�Wf0��� \�����v:�(���=g�L��Uo�X��%������j�F9��1�5�T�0NQ.��Y�
�Z��W�v?��X$�2d�A8���p&*Y�u�<��6r�:Q�ov�X|rv�<k*V�#��AUy�l50#����6�j_�[��D�C�+�-��L�k[����j��VV��$ �U�h�6��m��Hu��!���F*y?��(�0R�0�w����v�ISVv��-����$���Z7���{�:�����P�0��'��F�a%���Sh��c�g��F4N�������[np�I�{�7�.*R�D/[G��YT��;�3�e3��-�k����<�rj
aaP��	�
,>�6�`�}^F�"�R�I��b����m0^w.!��:G#j�Xz���3��Z���$1vY�&���1�<����;�t�!�j���������$�@�	>W�%�6!	��f�������E.�9b��dw1w��f���h;m�c�e�5�v�a�5����{�U�k�?R��L����piHZ��(�����*���������Y�mc�/_$�.J2Ox-`�����jH���z���,�\����;x�����od����:�\�W]D5�|���0���?G�(��x6]5�a{�1�b��A��i%���xV���YR<�IpJ��VMf��O�R(b
��"��f������Jb���DO�T��n@������]�>�(����Nl����4�����#���{�C����%�B�E0�E���nr;��>����?Z�"�@�9k����������m��P����QU�T�2�5	�A#����qH�_��Q����A>f��Q�.��7��M��3�v��H��e�����tCjTB"�����B,�a���|;}����p]��
���]�|�EdH��}��@��q�c�\`�#u+e��l9�{t3���-���������3�u��4��7�;� |��(`l�p�[�A#�xgC������Zg����v��F�f��E�*t�O&��"����������"Ht1;p�`������XcE\tA2gD�P��D����\�Ym��	'�Uy>R�prs���g���x>�a��+m���=�a s���;���;T�}���8b2:�@-nQ�@�P��9����>j�V?T��S��
�l��Dx��('C�>��Nu5*�%!!�r�q��m�-��<���Y���z�n,���'*�������~[��R=}uq����N-:8y}������e|�{p�jwj���`;�����������{��t���T��
�9��������
��<��X�{���x�n�?�`�P�
R-��P��$�
]���j2�)���_���K���$���:�(�(�4�b�8�l�o&����*3�(z������d�����tQ�^���Q���%=X�l����r;���7��|mms�����wwJQ��vs�g�;�`}��)�b�NpO��{s��LP�{0��*����z�
�b���\�L���K�i���!�C��������R������\)"�w�9�x����a����QK�Y�[o������m.w����0�c��
;����T�k{�&����Gzc���$^�u�Hh&���Y<��~����t���u]N�K���^Z?�,��OO������+lLB����o$�������r���e�8�`���L�?�P�_]gX��FZ�g���M��Q���D�+|�5�^�����m���E��M)����������a"�*�N��m����ee!����(o��/���v��K���k��BX�9���1][���i= ���]U�X�cH�r���(���Y��U�b�(�4����\�^a?~_���we���j��z)6�
���� ��p�,^�B��BF��rU(XG�a�������z����F�J	�2��1s>�n���{�kk���v�X���i���9��VE�BmB
�zmc�YO`D�E��$��y��V�}��6�yN��.?��+��p��W���2 Tut
�o"�52��B���<gTA�f��G���r�b+�F��"�v��
�iv!���(�z�e���j�\d��_e��+������~)��1��;����.6�0L�6m�]��/T�/�ouK@�k�`7���Zn�f��u�����(�n�A�sy{
���b����\��0�Z	8J����p�8l�7��PCU��S5�2���l:�gbt
�_z���on����5����`k}o��bZ�e]L-����E�/�Cf��TU�#��@�(���*����b����v�z��E����SY��&�L�ca����[���n3���� �Q�����U0�ap�>�������{%<ooHL���7�;�y���$g���v�eLY�
�2m�F��&�{�Y.no�I�.��6�s��Z4���EHIH�>
H��������`�`4���Sb5�[>���(7���.])���p��i�#�]��BKb�>�����&0��Zo����9��`��D��d+
����E���V ;_ RD	�.EC���K��+�9�`Q����#jg�����Z}/��r$�2�;�B��`���n�)5�NV��EW�H,LY��_Al,��^�!����F��(��n�?5��w��wI&���eN�Nt%���,������3��)��lz����d�%|��o�D��+��+Q&Z{[[�dd���-���LB^?�����N��]�����_+����fc;}f�<-}��	P���S��.�w{[{[�F����*�fh|_"��6�Ix}t#�F����8�>����Y8��d���n��.�����B�/8�4�5M�����-����R,}���`Ik��
,_E������i%�}��O�4����^ �;�����}�������5�Y�;
�%)��������y��I�������&�����-�dM��-�I��y&q�y���u��[V��p���w��p��+OHA������D����]G�����|:�/`��v�]j�u�������p}s�����5vv���V�ud���ud���F�g�������z��B������Z���\a�Y|�����W��B�\C����xE=I������Z�^���Glp��9�>�*I�O�i#s�D�x�!�� �jQ_�^}�.�1��#/�op�3H����^�!2{P��I��x����*�������4 N�DK���i���������.!���?��O~t����8=�GW��,'����7g
8^�S����Y�r����Y�0V�!B�+����Wh�y��L�D:$���y{G-sC�1��h3H���m�L��GI<��cH���K���6Y���j����|y���u�H�^�d�YW1h���l	��!��.@���c��7.=��kCQ��_Lg�l�I'�7s`{t��n�]�����_q�C*����s��JUg
�"v"Q]�N�$�G�2,��a�F#6��RS�?��f�`a���8��wD����%xyu1��m(�=�`���Q��>�\��TP
y*�x���x� R����D�"l���@���0;/���=����h�o���@����OH9���z�-u����E�����F�`��K�N�(F��rK#�F�������-_���P�N
��j�4Z
�3h��9����z;&�����V����W� ���������7@_q��8����	�@�q��������zA��yz�.�b�!��NB�]��g �@�������Y�~�.��c��n�@�f���!���Y�ru�m���Y�$0	��Q��nI-u�m����l�T�J�R��*yl>AW�o:�Ec��`�B�&	]�����/�_�?�����+C�\����;�����	�
�����D�����g����=���J�������R�,�/
>���.���
 ��n
m��[LG=]�2?Rm��hy�y��b
U�n{�/����[��M����!����(x��
k�s@���� �� h�������9�P��p�z��l���C��|��3kjY2�u&��}��h������	b+fs�n'Pi�P%'�W�-�����L��Y},�uN$���D+�"����������B*X�g�����3�)�!����*��K25Lrk�
O���`������U�Q��P�?�=`�-bcN3���>��9`�{e��b�.�pt�^��x����h�d��h��%�C�|IF���j��n+r���"g%��������^#�����F����$Y�rV���G����A�LG|Rj�s����% �i@-��XU��2]����������� 	�0��>#���H��������.�|X>�pT��+$��_�f4���`�������l`��+VNn1����p7��J/�yv|�`54I�n*�Kns#X��^�l�j�^��m�����yi8i�M�a.���Mp���]|sV��8�M�JRBE��3lJ��d�s�4�������5�\__�F��VM���6������	:1d>t�=���9dPq��@M~K.	0��s�zS
��T�z$APQz^/p�I���LU�zY��D��^�DK��'���)����[6>Y���VT�����l�%hL��������.=��+d06�A�H�0oj�����t�q�t��v��6:�	�j�p{������0�>���z����j���z�y����a�����I����Q���]�}���N�'�o����S<�:#�7�w�I��p:��\���;��G�1���H�������FZ]y������
&z1f�$)��6�*Q
N�~<&o��l���w�
��d��M�v���"m6/s7P��k�=v�h��!8+qD���UU�����U[%������$W���_���9�����p�\
��"0J�M���#T��2�1F�����$)B�$)B]I������G�����-��E~<�z�v���XS�K�
?��4gL�S���-��z��F��{�k�� l�u������6��B8������~��a3�d����v5J������r�.����D�f.�����j4���0�S����MV!\&��8�rc�?���_!���M:�X�x��e�VS[	�����3 ������|G�z�w:���\�W�j�����KI����D�������1Emo?r7cq�?N�v��H�#a�����mq�V��'���!�'�v��Q�v���Y����Vw�6�l����s01�w;�B���l�R��|\�{D��z��
�S��J*��&R�0Run	�b�W�w�{"$*�h��n��f�Q#����(������2�*U��;i� Ao7S��V�P��;��	�P��Co��jo>���x�,A:��`��Z'6���sPv�#���n`���������2D���@��N�����F�al�B�������p�y(uc��y��c�}���7:�!��%L���N���=�>�z2�'#��MsI��2���JX\����LC�BY]�4E��I����P�	N���r����1x�?�����#�����$����g�l�]����es���1�EW����A�S�D��2'��B2�/#���*SeWA�
�!E��,��V��fyI@=�&������M(]!�U�u$����S���x��)������*Rv`gl�q�%�}��Xp��S���j!�7\gq�",�cU4��	�<��n/L��b�<'��v�X'/��qO\�#UL%���\8b��>�ru1l��2���x!��JP���au��,�
`��sJ�/�R�<Y���P]@�sy���wV�]�Wi�"�9���.F����^
�[&����V���j�Vs�M�����%N�Cu�@��N��a�#}�j���\���H/�h-]�R��'8�EtJzg��V���g"��g���[���V�E���%~@��#������)�T�1UJ2�1��������/�����74�I.��:�J�/P H(y���o�=��1?��`������JZf�)2��b�����ru�$S.i�x��J�>(������O�wjc�*�(�(�$G�{%K0�/[;s�2��;�
/D�E~�z��'G�g��8������i�"���;^����'I�@D-�����z'
{���{@!���OHe�x��Y�V�����	~}0W^\+�;���+���$�;��m��}����d�_�?�uk�][�+$)���(�{9J1~��k�k���X.�Rx�;�]3���������w�T->m�����k��a{w�f�������
�7�#Jm�&�+��K����!KT,%[�qY=���F���N��b�!����t�pf�����0<�NJ�G�<��w����P���i�����0�-��dW����S����O[��I,DO��r^F�aD���8��w�YMb�	$��g+���pH��tyF����O��N����0����Ln��5:D��8/�$�j*��IK'��q:����T����cC�����~��g�-�>�\.����v�=�7����������t>l�p�;�?����
^r���!���Hz��&��P��;GSe
c�8aeX-�&�T���8#uK�1I���g�h|IND9k6�����S1�\fiKO~F#i\����U���R/����1�>���
�T��c�=1�:�[2[xR{�����?���m�7L���EU_��P�I����>+�+`��S���L�u���U+<�<�hT�zU-�����xMG3�Z,�����|��J��}j���g�[>/�zr��4*}J�>3��$�`!M����-�<�L
������A��F�e�'�g����M��+Yy%JK}���{=�l�8(�ixv~ss#��cD^MN-o��#��G��|�^�m�>n���1���N�MU$�;��u�qzj���r5[����5�v��bB\����1�����[��ZA�:�eEbMb9n?hE�hUJ23D+��J16��b|Dj��4�����y���=owV:�S	0�:��X����D�z�Hd������.�2!G���s	����@	��]��D�F�#!!�x�����j4�?�d����))_"����#K�38D�=��N�����$���~�MN�F�99��@G{��J���7v��2��������h0�$3��>��h��=����(���$�+��v��Mn7�=6��e`�5+�4C��Dd�t�~��T*��a*������u:�����
�����?����:#�T/y�o��P�l�\���0.�O%Y[{�|7��,Z�����3��7��[D�;����3o6�|��JQ.v�q�R(��44�pP�^6\�</~�R�7�bb��I����R�;m1��1�g0+�M�x���G��3\L��Z+y��GDF����s�Pl���6Y7
�r�3�����������a��i<�Pe?����a���g���:��rE����Z��m���j��F����Q�~��CI_�%��[��������k��X K�"�Z��0G�� �pE<�����v*� ���*]���V���\2��������Q�|o�u{��2�6hD�k�����hp=�X���w'm
T�Ua{�}|\�6�����������=o0�288`�;��R/H�M�u���S����x9V��s=����[������v���U�K1|z����� &Z�,��-LU�q��7�?�;�r��,xK����n���0�$�����\�zY��U��Rwt`\��{�W|Tt��+�}tP�&�g�5�[�?�9��m8� tNwP�
�;���[�pJ��#v,V����
[
������6��;@�z��X�����m��Bq�M:���x{��]��'6m�->kD7��
+�k�}xb����2���9�������U��3��7{{������Q6)z�N�jmeDQ�_Y��������?Y��[E�Ok�]V�������G�����v��m��D�0���o�����i���
���Q ��l�=����V�X���,����b����,���>T���3����,�e*�]{E�1��6���
Fpq��������"|�]R�����]�o\�EjV|�T��-��a�"�(��x}�]�����]N*�����X��x��b��N���*]\���V���u���E���|��c�Yb��X��G'����n���S�������)H�7����q;g�Vk���������
`�:�s�������A�����Tlk��V���*��
nK��qp��k0<\:����
��Hu��x����t�H�l�w�Q��@�\��K�[������xH�>�YFA8��D!�SA`;U�rQ���
�|Dm�;�����VQ�����{y�a����a���>������&�Za�]�����^QvM�O�5�`�o��>�����U:;���X�����2��?��n�T{W/��Ig<B#�x��`�a����
���B�iwt��<�9xWTN�Jb�1�H��+��kh�^x�&`mt+_t1���x}X^�+���rz�+@�w��5����t@�C����k�f}96[��h�qe�q��p�����w3�\���x������Na����p�y�uE�#of��J��$����u��z�����n!���`y��kg=&����`N	S'%���G��|�y���k��_���n�g?,1J��
�m �Te�����i,��~a2~:��4�?�R�K+"gg����-�MO�7uOM?�}��}5���,�)��d��h=���������xzx��U��.���d�N�'\Z������S�s
Gs�������&m$1�`�9�X$t���bP������}�y�������~�.�2E��"S��']����y��f��_�#����3)���~�;��.BYA�b{�Q\��Q� �p��@"�c����e,�,E����{~=��z�Z�����^�(� l���Q������-~Z�?�,)
��2�p"]�PI��
w�x��O����>�_���>qo�WG��d2"�#��w��)e��C4���n4��{������� �����
�P�����
�t�R���M������XH�j��H/Y����1=^1������X����������1���J��(�_�D������u
����Y�ZN��wY;�3GvF/�u����.��h�h�*{��	�(����q�!����/�F.�H��pin;	M����#6�e(�<���p3���r���^��~�yPR9Mi��U8��N@������?��G������C���K�yr������QS����T��cY1D��������(���~)q�����Q����>�����i@`��������(T�C�q4}�33���>e?���hF�+vB���D!�.�ZXw��E�Y���J�i�����/H���z�����K��$N���x2�so����Y$LhG��n��7j�0ju:���<�s�
#k	�D���� �cz.���$I���!tF��~�p\�tp<y��2W�]Gy��z/��K�������#x��#m!���}6�U����N���}cM_g{&�t]��}w����V�d�=�E�K�����A�c�t2����[��i����(��P��.�	��+�����x�L�����_�:��.2���*���P���V(t�G8pK��&X�:)����������fB�Jx�2�VB�I�
�X
�]L�P�@���J�����VP�����n��~�r�����������5n�xp��x
���	R"�mJ
��ue�T(a�	a/_�4�e����`���--E6�+�f�9����-,QP��w����9)���&�x����rb�I��5[�]DS��<��k(L��'��t�
�)��l���W'+���Da@S
!@�*�P�?�F�$#�~Q&��d���h\k��m��*~M�]Md�['v�45m���p�����H��7���h����K
�j�]�a�`��Kx�~>��9�w������t,r����y|��p_=�T>���$s��H7�#�
��G(�9����Ag������SUb��E���X��O��\�af���!�	��Z�l��@���;yIh��P������S�J1��B�0�L5_j��a�p�2��2
f��*����k���eNXd��.tB����R'��u���qX���Y�[��-x�E�x\�<��9�H�:?w\�������j��	���^�^�=��{�F��.�{��t�-v��B&��|uq�6(���1]�E0
�H��n��]����q^n�8O'�%�Y|�s�F��#���x�FhM���(&����v
8b�bD��-������h�[�x����'�{.!Mch�@"D��]��9�N�o�u��>�'�����o��t96��Q�|�^�pJ�U�1�����e@l�CE:����s+��=��`�Uu��_wqj�6�N��0��� �1M����j%-��4CLqS�i�D}])e��<����Hv��.;�dOJ����U�6��SEl�e����G�..Z��%����X�6�~�^�k�^�_[kt|?��H��Bx������S�����1��'I����9{�S������"Sj*;.J��f�}zmb�|�]Mv����~��YW?F���+W2����S��dE����O`T�TB���8�N�W���Gx�;��Czs�jw���+����D��1>��~�[%�lR�W�Ul"
Zb����S�j��UMM�@-T�G���ST�B�*��6����(It|}�����"�y�*�k�T���w9�y�R��#T�)�7���F������]���o{�
������za���"D������{	5:�����4�UI�~<H�tf�#����"��nl���PkKsh�8i��dH�l���ObX���r��bU	�&�&%�����w���z�5�����8���<�����l2�r�73�9D����H��T�&���;��&*�6���}l����h(7R�:Yg��0�DlA�7�Q�zA����suA~7,�S��� �t���i�����{�Z�Vk���"�4�N��r����7&��h<]���Cx2Z�[7�%�P�]�?89��*�y�)G�r3���K��	k�
Nr���
�e��{�.��
���"���p���L��&���D������>�������;.�z/i^���:.���xG�u/h�zA��i�w����C���s�h(
��`!����\BG�s����[��`�70AC[�l��z����?�~o����8�',�$G�G8�y����d�t�t��l)����D��f�������;8������=�}��1T*�\�^�,N�J\���&���\y��+��_a+�#6�D:	oI"����?-�.8�L�s2��������Jx����#m��Hm���04��W�G����O��l]�c�g���*1�>cK���o�C.�n����g�`��	�����V�5��lxlH<�F���F���!�X�Z�����V(<����q{|U��<����O�J�+�t�)7���?!T�[�8w���G{9p���x���oo��G����]�J<�S�F��<;�9����;'�r�S��r��xv�s��(/00B�����t�k���k�Z=�<o�����v4���#���?�6�
���8}
������f�V/�i�)ln��h���P�H�#���eX���i����_������3���v��T��)Ai�xUR��.��������5L��V�+
nb�}���.`�=�.j�AEn�u0�����W0a�+L���#d�]���.����^	TK,��������|%���c�^_����Jv�����+�_�{��b����+g�Wi���B�P*f��K�X�D�5^c��=HK~�5i��5���f-�#�k��?Ve�wpaA4�a�H�|tNb.�����6���`�p�q=�F�^��3�8��������.��l���U�2M����G��c2~.'�)sZ���)c������-Q���*WLk�����&��
�i-����-�rP^��:]��WhY�o�Hx��x�]{4����*<�-��(b&4zWHL��H"����?���%!������.o�����\�?�u+����s�><����G����a����rr=��u�L'5����N����z�f�|�XH+>�-�i���m�ka}�F���F�U��UP���Bw�,;w=����u/��a�.�n����"�w|;"��A�27B:Wi�2 ��+���]!N�@J��*Z����!�t{�#�C�]8�E�Wiy-p��+��\%�����~��P����Y,����K�`�- �UpE��YC���[�,�������3�����
� �qE�*�_���[l�9EPk�p�������B8�9^J6�$��GCt$O�+R�'����f�;"���1�������tE������_�O���[��:�Q%>��}Hnd�����r�Z.p�e~�7�'rR@���Ei��c�"\�\S���tH�<2N�ge�0h�M=�f�Qh����NP$o�EV��e��I^���y����&��;���`��"C�0v������;j�������HE\c���a��'T��rAH��(�6]�v3��JS�t%��"d1���Z2x����i������#������bm8�x~��hZ� H��d���&�y��}�W
��Fk}v<�bsl�x�J�S@^�b��
!fU�KK�f4�a��b�ea��wW���j�s!��UATL�*����{�,�������CtZ��Mn�S���vp+�"o;9�k��ulQ�������WZ�.h\�e"��<X 3V�K�0h��{m�}b}���f�;Q}��� :#K��(�bZ�
d�9�����w{'��<w���s�l,��vH��{��u���������a�}��j�[P��[c1��k��D7Q�O��C�]�����Q{��Mv�n��~�o������g�����p�P_d�bKSj��,?�"3��t2�k����r�2�LB��D	y@���>s-�����-�H�%i�`d�at=����d��)-����e�A��_T���l��$m�6=�QW6z!�e|�XvW�X�@���QQ�d>a����H]���9��-�,���<h�~!�Q�b�o��H��(�}�^�Dr&����S���������*O�����������J�$�Z�!M���L����X��&���~��h0��K+On��gN
<�Sw��2�g�7x�E�!A�����GIN�"M^&�K+?�~����!���&�z����}C��[n��9�i�>���K��C
4�M�8�aI�0�)�����x��r����n��!���g B�rdG�<�8�E=���2=bb���ZZ���6p����l47[�@��M�N�C�xi������Oh�7QH�:�68
@K�O
�|�f���I�������nXV�2���������#��J��9��z}�^w��Zp��l��!��A��d�^N��Ucr�V�������QV19�Sy%�
A��N�����S�^;��J�:���R��Z#��G������ssY��/�����?�+/����(��W�G1�&��Z0QO�%��d�Dk2mn������SH=�OL�����H�O!5>��$���T�1�RS���I����s����z��(%S��L��sNTSm�K��I���+����3K2UTk��g���jc/�B-]��z��!��)����G��F��Go]G@Y�.���9��)e�C/Qr�bcCPR0d��(��O&��o!�JgR����J�M��)V4�QBXG��?�����r��Q����yiqMj�|uN����p�y.�������}O�3�3�yn�B���jI�W�U����H�AiXR��t�yn�Q*��&	3�
�;b�H�<T��c�]���-}  >�k��.����x�g"@�8��(�]Z�i�l�����z�+��D��-�P;�������
�A� �����/�3�H��n��(9��iN���Y���:�C���>m2���1�ON
?��F��n���0�Y�^�d4��K�aFF�+�i!��}�s��,g���j5��w���8W4��
qE����bX�< �h+�!o.&-�S7�f�TB�B8����u�y�����&w
�mn��+b@��KN�r�����|v�����8S8
�!���/wL_�f��\��n�O�K���TvG�k������EK�v'H�'�3I�	�$4N����/A9�_d�-��
���]��=b������\s���g�x�~�	M"�����:e��8��sbf�A������JU�;��64�j��P��������3?|����Q��67���y������}~����7�q9�
����
���o���O�v��?��i�{��/�y���A]x�@�p��������+�@J�QmV[Uv���R���������s
�W)t;9��&���~<���=����2�k������ ;p����6��MB��E���9����S����IxZSJ����{�1XO��`=X��������P}�A
x��'k��2��&~ ��������)Ci�P����@B�o%,���;hG�����3�����,��<���A�*�wU2��JL��'~==��d 4�"'�J�1�X�z�Q�~��6�k��8�GM_�� -DR7Z��]��3����sB&��y�}�@�'��������VUKH4���]����hcDk���R�x[�)�AO���h2�T�l�B�\H"�����3��V�<�qv��m�-�(\�o���=9-q�D���������vB@������tH��GY:�B����.�e�.��s���;g�k�@��VV���'T		��r`�7|��K���*�M]��.�-2�_������>�����d�"(]B��0��TFS@��L%R��3��*��~��s��X8B,��6���?�w����w���
���o�~����B��{��/�$���{k�I�6;�b=M���l��k'��s��e
�Ph�A�V4�`A��Ibg.w}��q
�m����Q{�V�����3��=fks���T����I�j�;�>Y!-�H�J�����]&,�kl�vF�	�^v!���!'hT������2�����1b�uw��@�8�������c=�4/��?H��uv#4���#%)=����e�P�����h��K.�9H���Y����wm�!����AUEy-� xj����#"F�|%�h+Yo��.��$���AK�c���w�\5�����<�$�e��P�d���d�]�(�m��"��M&1%��,���W��
v�H�&W�c0��
�(���S�P)0iF$@h�a�~��$Z��hJ;UM�*�Z�������d�����U�&P�Ag9k�
�������5g&ak�BkLKW�fl~�w�s�Wl�ao4�D�v>���A���U�o?�����9��{�?�I�����m;7���A����(�Y����������*��c�P�Q��*��7b�����:�%�l$�`^��.�u�#XBm�����������p��t�����q4�w��v-L��n�#l��l��2,'�I�������i�J$<���4.��Vp�����Bm��Z����@W]�rm%�p�J7e:�	�j}R"��#Z$�0�&iR��!�����h�)-@�U�McY�k�������������7�������L�Q7��N���W��������`1m[���\����~�?p���W�[�stp��
�"�����!>�%�.a�"f]����6���3�P:~���i��yc
m���N�S��9�| �)��V����]���a.��_�����'������S��`�1����o�a��}��~�|�KN��S��#U�-��cMa�����oWwv�����ZP?Z?Yi��G�,�h���,��b�����A�:7����@*R
3�B9����K=d���o�-�8*�(��~}�����Po~v��oR���7�6������g(vW���Z���k�����|i��X�jQS��������FT�E���Fk#�["��*5�������C�]����n����	M�;;����7���U
�n��,%{/��=���-5r�q���U�j<
�x�������XI���2�rpDX
�b�����
(�b!P�}���c:����	�-z�c�c\%!��A�
G�p}1}�pR�6���!�R�
C#�gb���M[#,�6yO�AH��_	��cF��I6��s�����q�Q=Ct��v}o����S��R7Z������0���{^@�$���(��r��^�b�s�>���f���x�3��]D'��IY��g�=�kwR
G��W������v@��;y��z#���:�w<^��s	�J�9�`��L�R�����d5ps��r��d�^]�CsG��I>E\D�����]� ���w��+�*��
�?��!�F��^�����]jC����+�x�3���h�
�(�~1����� �Fqq��-��7��Y�9<4���I�+�<X�T13�!�rs����:��^�^_
���q��ct��f:��f������� �M�������v�l���7o�Ui��|JG�G���~�#�w����`�`�����6��o1����%��'��n"���Z����5�����������Y���h��K|�l3�2!_��JC����iWj7Z����j�W�Ld� ��Li�tj�n��������:�*�_�bS,�����N�Q�uc�dF�K�����5�'�f���KV���Q��Q��H�2HM�`0����m��1�������F}W'3���(�#Ad�kF�\5O��H�s0��~^�:���#Cv�cD������cZ�3v�d0x6�Xb_!�����l�����mn�B��	��:�by�z�`���+s��K���i���G�V���x4���XJ�AA��f���7���6I����UN�|Z�����L�pE���:���0c����3��b��>�H��������|������S@
��gy�f��+��*fG95*w�5�2�/5&�/
�_�h�G�Zc�UF�q�����f�G�[{��n��$c.�Vc�����m\U3n����A99��so�z����0Z�e8R�,�;h����"`���fW���:jpDHM<��}����__���8��
S���e+3�f7��v�=k�,����=�Y��:���5��Fp�eVe�Bum*R�q��-8�����4������=��z^�{���?q�DSV0vF]����W�Q,s]�.�����4�y���[���+�;�"An���]^���U��)������9nr�p���8����v����j4��}�(�9��_�O�/	��������������G�C�7�7I���������.��U
�q������h�,u-�0-��9��dW����	�f%J>�a�D��h%��l����r1i��(����z����7�;[g�����EL�PU���2�N8��������X8f����53�13K�R������*-OLaD�
>
��~'"�M�.���Lh�|�B.�7��h�w]Pf.	���j�s�wb@`!��W�s.�����Ln�b����9��(���3y���4?�q���_*��s�w������riS����
�%���9X���76�C��[a(k(���$����I@�����V�Kg��Z%����h��FU��#����n�>
��}�ZZy�"��������
l�(who4��p�����N�������np�?�+3�Y�Y5{���x�Z/)J��w��w�I<fC7��ZqG��,!W����O�����}����8p)��cN�1\%J�\>}f��<)���t��y<�
Ks?dr��B�s����!E,����,�Zi�r���B-NI������8K��*	�&O?t�n������#:���R��!N��I�u�F�����/L&�Ep��@j�n�p���X�O��5?9O[�.�����"�Db0ZA��;1�i��� V����NFW�q��P��@������I�l�����H���2)M���U�R��J������{@ w��D�p�6����
�'�~"3*
[��cl
�}������E�YD�����s[�g�C�t&g�qk3���q�Q��f��B��\�IY
9���vl��m�5��/`m���~��'��bQ�Rq�2�u3����g>�\�p���Zu�h1�����YP�}ic��g������v���{�8#�h!����6�C���*AQT����|�^���.E��\���*�x`{Hr��*���>��8�0<'��;�i����$�����0OyxZ��8l�:	�V	IS�TuX!������/��Y��0�|
��b6,�2'!����a�O���L�|�T�i|�L�o>J���
q�A�R>=��j��C�:}_�B��_
���}�lbe����)���I	�dR"c,�E�u/.!��wz���UT<����T�o�J*>�����m./S�qT�/�����q�7�N�q"
��eZ����F�)e�S��1��&+��S
fVN�O�|���1����g���!����>vG�iilO��'X�v�G�����:
z��cv+��d��Q����u�BP��6	������BL�,k�U�L�3�jP#�Hv.��?�UI���B��]P�[�l7m��c���DM���{�L���e�F�(���]D�hL#|�M���2�I�X_���WY�W�Qo�}%S��M�D���'R����R����Dc�])x����dO��� ;���`v�r�B"H��B
��$|-����F����S]B�+E$z�U�2��� �g�_lj�`�h<hb�f��x'�������;�F�M��3�+_���&R�i�����8�q9��5�@~�����_�����RYc�`*5�2s)m��R�r����8@���9��n�B�i����	�Ya!�����_3=��!1�����y(���5SS3O�d�Y�1�Q�*������z]?�:SH�#p��gK�}�)����3~����b������l)LS�tYw�2)-�R�K���&�����$��$��!}���Z1�gK��K��z�@�����l������p��P+PRn6��>	1M�����o�wT���_�w��~����;��?Y����1����������%���;�f�wg3�b�1���%�k����eaJ~��������]����Z���A���p�Mm	x,�M�M&B�`7�a`����l���-��H�x��t-IP�_*�gse�SO2��[��j�[O��cg}�fk����-u�1�W��~4���g�;�L(YW�����n�����j*��L�d��6��	�e��v�J&��a���i��R|�+J������>:>����2�BGG�	_�x����;J{r��/����(lyq����M����n�S�
��4�b�=����rvL�*�r�W%��q��������*�O��@���&1���"_����s�
�b����o�L!�Ozy�K��`bCg��r2���T6��xq����rn�t�:�6���	s��9����%��w�60�xRZ	�GZ����r'3���Pn1�vy���������'�d*�J��U0����,?�v/B�d�g�p�3cF�����q���>q_����mk������d�FDk����G��u���<V�?���d�x�?��B�ppDkPVosj��C*G5#QV�M���'�P��$���l������� ��r69��Wun��"�#�3�e����
�K��#a��5XN����s%
����E�RD$��0������%V��(>���z���/�B���p�+@�H��@��#��[�O���Y����C��uq1�.(�l��-�iO����E;�=�n����6Q�����o�X���7����?��N(�
Z������	rZk;6�W���o��K�'q6l���M����I�7!�������g*�.���^�yYa�����h<5Hh\��+�&?G�X�&�b�y�F^5q1��]�d�c�4
h�� ��9���`�a�j(j����E(LM��>JX	�3�N,�v�y(�e�g����������=������j1{zO���.,�G�Y}1��S��B��"�=����~���+\���x�\]3���MJ���6�O�E����1���JS��tE�@[�gCg���Nq*����Z�N2o���?w�����J�T���	����:��cR��S����;�O�+P����<�5C��E�5������+!!Y�Xm�K�\`�+M���P�o-H�����XybK<�7�V�R93K��rt��g����`�u�Mi.���L�\��.�P���Z�g+�E���!�� Qw��d��<���s�@�=���[��8�C�p	�3��\v!�g��5����^/�����DT���]~��|J����I�D<LO�^���,7���',Ti��I�mw��}tBv�O�Bl�Pb�W�tQ\�1�4�
~vHI�O;�;�i���g�7v���Q�4������;:��deB�S������'wg���z�T	�^���������(�H�������R�_JI���'~��z�F��oz6?��|�U/�� ���,�-���z�k$�s��DS�tyQ8�n#K����`���1��
/�c~������������
�����7��J�dSB���W�7���B�"aJz���1]���'PR�CNR����1�N��T:N��0��M�Z���{&���A��\~���%+�H��#���.�����=a�fRL����<")�4W�����b��l�~����s�s��)�,�H�xk��w��D{:LD�H��P�jl�2��/��������F����h"���h"���h"����C�w��|{���vT2N���g���
?vu6Q�P-�N��3��)���v�����N1���N1���N��~�S
�)�����(���(�
�o�&��,�G�?��xt[��-�G�+����)*eB�)z����d�f?�D�/����f+����r@�����T�N1���gu:���Djw��9�L:� �bp�K��$�p��$-������,e��x�e��"'�E=N>���J��������)C�^]�JU|�i|���
^����wU(LP�YL�;=� &�qyBo*
�-kn�nV���\����wM;�d��Y��r6��~��60.��[o��`����2�d��h�_e������zdu��?%����������8�L�Q�Ie*�O:��� "�C��������Fk����z�������$^���l.����qiee�
�?�IV��Fu���?4�l�I4�D&B~����7�������t��i4��"��;����C���2�]MHgt����I��_[����w1]_�Q����`p2��c��Z�UF�����&���������������EA"��b(���P�Z"���#g�3_��5u�������^�����	�b"X�?�Z������Z�e�Y7���9s4��X�Z�V�6�?����l�k����*�����r������H��c�Km�����h���#a^W`��V�[���;^��;��A�R6e�xPNg�q/x�
�����|����l��E>-�_'���
F�t�������S�����!��M����@G/S!�9�e�j0��,�p�P�R�-���gn�P:�b�R,)%`9�V:��M��z��b/��'�W������.
� �<�)V�%+��e<n+mg�>44�~K���$�!� ���gd���=��B�|��sYf�S��.
�u�������Ak9(/gT���SyZ�r��F)�����4�u��\��p3�^�k�����������^���
^��H��I\�PJ�SI�v��e������C9��|�� �L�}*m�K|�����cs��6����������B��7������������r��Z��s4ww���K_�W��S��T�I~ �Y.����c(��of��6_���������J��/�������1�R�n��p�
7I8
�`H��@7��I��@	��K���NG��:��z��>���.X�!.$�z�US�Q;md��T\��tAd����2�f�%����x)P�.�LN�����0+�;�Y��;1��J���3�cF=x
�=.��NV]��)���S�Ne7/_�zE�>+�U5�;��[�k�FgU*A�R����2�#c�����P��(ph�T.g�;T�|�����5�Yj�e��Rj��^��������}i��gV����o�5?��N������y�#(�2���U��{��u����t�iP���q���!�|�P�$�\��^H������
�I|��s�����1<���G�?�C�,h3@�LU%�r�>#�l��
%vG���0E��`g@��~���� _e�
�>��W���j5��`m9�G�r(b1Y��������:R�����X��s���0s�n&��A�U}6�N���f������)I�g�u2�$��B���Y�	�K+On��`0���.�!���p�+w(��	��U/�%9/4y��Z#��!�
�q\*	qW#�H��dwH��T���������%�\^M�$W����`�%#�*��:I���������G<���l����j:qk���e[>���(
a��`\a�������i�VN�)��]�����GY������t��s*�n_��n+��SK��A3(|EXO��^������f��_�iG�;�������]y�M��!����������pruJ����S=��?���
p�m�����]G@Y=��iR��V/���N�������O�p�'v��:���������3EH�J<��S�h�p����c5�s�}H~ywp�>^�\6<>9�%f�y�v�dN�$��%�6���]��BL{����������S4&� �0�!����G]��C4d��3����D��N/�2���rI0��k��*�Zu�6[$(�Q	�&��Nu��KJ{FN��f�H,�l\������k��������'��\����t�/�J5�nKe�L����\����������kD3�z^,��Y5��[���=o�j�0#����k�9q�/�jx���Sg+�U���CA�g�Y����E5u�X|�f�m�gS���*;T�V[�H�T����6��*[?�M*���R�L�����&P@�����	���
�3M|�f�'��M��2��6s��0����q����(����:Q8������q��@%�
�*����A�;������m���_�dV)���W�.��
�4���Y��	,��������-���J����K2q�>e/����h2�T�t~�dX�/����Q,M�m@��7��R�@!a�F�#�,����:��;=S���=��i���!(��������|e�db�R���|z������B�l?XS��cR��������f�������]�~�B�1��m���
'�1��Dz+�a$#�qu.��G%���u�;;*C������������s��O����=�xj�P��j"Y�
7�JZM:�����������?a�A]�f�3L���
����Qa>���8Td�/��w!���#:K#���`6g�?H��u���GI�����(u���N������=��v���5�����.;9z�V�"�����(�J�4�����f�I��/����{/�/%C`.����ap������l����l�\]�_D�s�i\	�a��RAw
��e6���t:�F=��g�������8��M�LS*�PZ���\e�)<`Z�:�,�N��S�*�r�,��q����������,m�L��� ���[2��mFz����>y�j��
7�C����i��������<�k����kj0W�������Ad��*|X���~�|�KN��Si��d��5����W��]��!<��h�V�7�;�-�-H�N|ss?Xo�6��
1���P4�N^��_HI
[h�	9,�0�u��Z__�=��=l����}vo��ux��X�3�+z�t�`vy-<��O�!-��TX-%\a�;���k��Zm=�h>��Z���-���V�o���
��:����k-���
Gh�^������R��.�S8�R�(w�� �\����`|��)��Y�\M�J�F��]��
���G�P4�*B�<�Q�|;tzK�"�������TIx=%
�4�'$��/>`����3��"�!b�s�+E�04�yVwnD���M�T�����&�U��<�
I������^0����n
8���>:B�@;5�����~&7=������Z������|sMy9_Q��W��(�UK��X��^��8��(I���;�� �mv=Shw[u�� |�^����n�Le�dl��"D��O2����:�<�
4$;���x�z�\L�*��eFL��H��(�/���E�XmC�/HZ�
���3�0vI�h�\�:.��=�0c�"�9�:=�����?1�>�K�sf�H��5n�u����\9g�4��0N}aL6L�r��,�\��sj�Vf�����3/'���^0������O]��l-�F�s|-�_������Yo�������n>M�a�a1��q�h���Y�7���C	������6o>0����G�[{��n��@��Kf�cTq���4�����r^vf��1��c����^tHJ��
�.�����O��.�CE�cr����P�-���J�k��h,T����H���_i/����\P���R�Z��|����6'������A�{�Qy����C���8�[�(��uf��24�+���`mv\jB�7��c{�'.��j(G�v�P���W�����,sp��(�[P�����;���JR��/�P=�K�����-/�[�3�5�D���2��`��Rxy��,��
L^y���'�j����_G~�;e���|J�*,
�_��n��<7D��78���O�������|��}��gO�(������I�	��UJ�q�[
����,<d��{*��<���*kHd��0�V��oe�_�E��Bb�����_"���N��p�FgF������w������"�(/���P��}hUwj
���*��n��;=���
����C��Q�MY
��s���.��b�P���a7����Z�����?Y��$���x�Sj���T&K�����a,T���1�)
���v���T�!Wj�BEZWp�V�zz�V��i�� �|^e<�<���U>l�u�N���W4�%j�Vm��@���/�O��m�2�I�Q�:�t�:����Z�`d��?1(2Q��58�R�of*2��bu����'��������=�A6��Aw���e�<�o!�(�z8=c���@�+������F�)e=:�x����&@�@��p�������O�������I�����C�����T
��T��^
���Tc'����[?���2O�t*��7�2S����Ch�:�gE������':���N�x{vH|'��
E�>������3��L���5�,$�(T5`��9Z����1�0'���s)�Vp)�9���"P�X6���M�0����;�?+��)����5�c�Iw;�����[�T���=���M���0X�!�B����	���P�5�����M�n����z��������.���0�eC��M��*�H�5*�&���$��WWS9|���
��Jd�1xvH+�4�����	�[�V��G�b������R��J������7�{��
�G���c��'C@�!�q�$1���������P�N*�A?��9�k�C��#A���h(	^���V�;�Z0U��1#�4�kT�mC��j�G�^:��������H3�=,��_|����������)8fB���$�&3Tn�>�P�=/�g��]3os�]�>���������G �`�%K(�Z�	..���1Wa�L� ,�lf���<X&����P�H��ao������2K���Uer����y4�{�f�����YJa4h����:?(���GxM��who�t�8���TxA���W����}.K&eY���Z2�F\�g���T����^W���0�R���N�y�(&\��xo	����x�}/s�$~�>�����<�������8
���oD���L�AV&sX�pf�������
�w�j��7lx�`�����L= CUU��JHe�)%�B�0O�(i��J�7=�����������M����!�}�^����h��./
�KTY��3� ����V�1��$We��L������*r�[�,�C��b^!K�0���V�mc>Q2��m������s	�L:� �b0�)��8�p���"��D�)�9P��XJ�vx�0Y��=)�/� �
�������b����_�[�����HJo�O
0002-JSON_TABLE-v49.patch.gzapplication/gzip; name=0002-JSON_TABLE-v49.patch.gzDownload
0003-JSON_TABLE-PLAN-DEFAULT-clause-v49.patch.gzapplication/gzip; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v49.patch.gzDownload
���`0003-JSON_TABLE-PLAN-DEFAULT-clause-v49.patch�\{s����[�8����'�����������+)�d���P$d��I���xR���I�%�I�����b����X����3�����H��;���7Z]��w�����l���h����������
X�uL��v���2���1=��.7��;���W�m��
�g�z���Ljl���O@��1�}�wZ����Z���/n��n���N������f����v=f���v9~s��z�[�����^�0�5���������1��r��a�6d���AK������&����������!�X�U�:��7���;u�;�� �m�<����e:=��������7�rE�@�R �]�c���:���y<,t�`�t�M`�~S7�&�y�����F���n��Q�g���66����qx�\�����\
�x���:3_b������s{%ev���h[~��":ia���0~�q���P�M�r��m�CQ������������vw]������	���7��o�rY�zle��g�Zw��Yc�~�YL<�\�/W+5��2��\�+��Z�z��
��,X����������iFw�h��Vg����Z�~��&�����������6G�>�����������j{� �S�?����g��%XX�?m�5�dC���%����(*�>c������w�5���nox���,��s��t�g�z�5��f<���s���~�n2c�a4�����
���!����ko��'��rPeJ=���U/���&��@w�~��X
�/�7�T��\�L���"�Zv9=�3�e8V%U9`�kO�9�<����W`�,�8��j����
�?l)���3�}�������l��NqA��b��6�B�68pO�����_��@��e��	�z�����Y���]��n�A3�
�Z�����2��~":!M����
D������
�T�z�*�f4U�vm�r� �0<�y�'�O���A]�4�@o���v#�i?��9�l��z��� r%�A�������	��Pl�E29��g��%,������m|�iD
U�+-E(��R8EW���w�*����m�HF��"�N�o��'� ����2�6�v]e[j�B���):7��e�0@}��zP"���#	^����B}{s5��HH#&�)X0�Q��t�&<����}g�?s�Y+~�t��E���'&�i���L��zFtE@���ZH��2y}�������,��C0��(��uLET�J���Q��P#RC�\
����	����7�p�
�����l������i���#�i�V,�H���F��A`<0����v(I*+��CP�;�o�;
�r���py��MQ"�H3���H����^��,vm��@l����g��H�)3a�$���(�"��04Bj��JR��)�u���������<�]�`����(8mB<�E0W�	'(3h�[E��{����+f7#��i�P����+�Tdv&b���W2����P�4���2p`��U?��6o/m�d�RC��v�
X"qP���VyH(jCIi#�����QB�
�8dT�q&�
�J(�L�WR��3����O��F������,Sp�������p�8c`W]��ap��j�j�K�{��8*�'�[U��B-"b�^���
w1g*��4 ��D�{+@���L	���U���t���P����c;�/�tj!|��_xE��Qq��}6�Y���Kt��r4�X�k
��.wa�h���o�~�d����Lh;R�k���n3����	��U���TC�}{��c��@��(�-~�6�q�6+�s�%�����)P`r�'���(\��K������Ps�l�
��8�@����[���%��C�g����_�]I�^���:�����l��LS����X�6o��Q�L�n�#Ng������vqOE����-�s�}�"G��#�_���.nn?.&7�������eY��r�SQ>a��[�������fvq~}>�u��x~�L���A��jh �s�#��D�p�n���8�K���L�����D��aO�s�Ev�`^����&WP�q`R�>o� �w[+�/$!��P����XP�I@��&[��rE��������]K*q��s��\T�no0X��Q�����.�f�kQ%��D#�w{tRr�����k����}%q��=�����S)*�b2�I�9M�,�W����$��PB3)�}����.���L���d�[��`��E��(���h��r��{����4m9Z��� ��)��D������/�G�"����^9+���WP�	�$�����y>J351FE�o77����T'�)��&�,,��"��0b�	JU*$wH#�-���������n��g��<���`�fG��K��@�

n����h�K}�.WFo�U:EHV�����Oel�����e
�L�����LW����Bt�k����\l��$��6sk�$2sS�Y<�m��li�U�Gu�7�q����%sb��u!D����n��hhm�����a1D�4��H����t�W�MC����e0�>��O|����[���?��
�=�\����m���k��8����^]��{�!��1Ze��-�J%:������+�_�l!j���G��LO)�6��Qj��va�]��#���,�������%!zA�P����@B�:�v���g���:~������~���
Ca��a_���k�t3�O�{59���d7�?��s,n�a���}�f�����L>|����%f���9_��S��-A$q~}=�f�0���1�:��s���T��O���0���J��'3v{s}u���#�%i����Lv��/�4|���2��0*
?�������L�n�����z��HOo���)2&����>=�n��<������i�����;��
��xL�Q2�^�_	<Q��H��������N�q�%T��,�tw�����H�Jh+g��fQ2�Q9a������Q��x;���:�F�0�5��{�����{'r�By��NW��
�pK
��ja�O?!Wb�T�#����'�R���u��'���-�
����t�,�����Jh4��b?&����C�����j�`���l~�v!,��ot"*���!Y�`����! �����B�{v�:q�N�"��d2�U��f������s����N^De�R�ex�&��Bt+��-E	XQm<�)�������2a�i������<��)�)��l2,+x:���N�!����#
���~�7 �����5o�C����O������H����w�^�H�q��������[�K���D@>��<QXB����%���H�
�>�%|H��3�&z����f2J�W�h4�z�F�op}��msw��%W0g�
�vk���g�x���\�~�������VV�)��_�K5cGFEnb��A}ezk�[(��l�����'v���>K��-��K^:,����U]�WZ�-6?
�)�`�#MY��RO�Ve�0h�������bC��B��J����I0v����~�U*�������kGW2u.w�x��	��t��@�9^�U��,����i��BR8�<�v�i�����H]��F	X�HE�d�e���"�8�A�9��u�w��lz�m���m ��R��/A������������('V^k
m���(5��g��W_��$�d%��uc]���'*��U�S�� �XD}��+���U��[2���&6~� �EM��e��3Z"��PJ"K!Q������n|�$
���P6����e�����!;f�)����a9X�Y��B��3�#��"��@�5&�����Q��������G��.=����"�I����v�jE����E4��QtA�N�b7_����~���7��H���a�1��~[k�x�����z������T��g,�8��UCwf��
�����=��
%Z ��@@Q~��u-�����c��1nI��g�q�n~����c���_7���|�q��m�=���I������r�&Z���}���h�����3,e��|x�U������_��_9Vu�[����z-R�%���d.�k������J��������]Zw�@`4_3����nRn���,:a5k8~@	9��'Kh�#��-D4������!"��qgUK�#'��z/�U�RHCA	��3�_���B��lX�}���(�e+� n��g&|Ub���*9��{Q���D�����u����'�=���kl0��Lo6��"?jB�"����S\�R9W�/�B��s]`*���j3����eC)CV��p5r�U���AU:E��y�����WP��b��f���5�B�YM����Hc���f4��m��xn��ec�_"2�*(+��
��]����E���n�)6ox`���	DZ�{�J 
Q��?�1��fN�t�]��J%A0���
7:5��"d.Tx���`C��?2@\��Zw���xA@L��ma$����Ja�� ��2�� ^%���J��-0�S����)��P�",E"�S�,� I���Br���	8�TR���V�S;�"w|(���~�Y��6cs����k+:!I�,W[4����Y&
u��}Z�$��`�&K\o���`�5���TD��v7;�A����KChSq��K^�=�OR�P/�#���3��M��w#e;F�C���$�~;�����x&`�V��4��o:��N>=�+r������"�
<����NM�`����C����a�
��lq;�u�`� [l����S��S���6��O�)XD���Uxb�K� �S�B~:���bZ~�`
���g�.|��]�)��]������������	��]�����i~O���\8 ��Q��@��n�����+�����)i�����qDSF,�3M@�����6Q�����Q�V<�j�3�z�h��E���f�7.����8f��7����re��qDL�/��D��h,w�@�&
=a�F�{O.+'��b/mv���S]������UA���	$��-�I����Q	���h&��`���+5wMHiy�����i�]z.���=#�I���f4�`.�C5JG���2MS��'�!��y�C�j�Dj�H�P�	W���W���i�!�#���:�H���/�����d�z��<�k)3R���7[��+�����Nv�WC���AN�^?��	,�d=Dz�b�Z�-6��8�MeE�qR���T�I��&L4��f����h������:��>'�*�m��j;:b����x�Px��E|y����`Uc&��Ft
%j����v1���l�����������_tc���XD�`-S�0��1����r�O���d�P�����_X��T���0HYZ]e�R��/$5���+���++I\@o������jr9���r&������x)_?X�IraXi����@���| ���SRX^�,N�
7`i�\�uO(�{%�*�H��_"E�1q�f�XK��v�����_�W@�U��4��f�t1r���!e�d�7%��.C�1�@�?2j�������t�����������n�J����H
a.h������tz3=$d�����[�h^���
���hh`Gx��wYC��PlE�4�2��H��O�N����e.,�Xtv�����X.+��tu
�����q�	�s���8O�}N�o��g��au�+�p'�0����;Qh��3�?�f���>����pgs�O^�*�R��Z_ZZ-*�yT��K�WS�������!�>��y"�&���	�K��M�
C�x�a���/����%��'��]���;����'��@�2����I&�VY��7�SB��Y'�/�� ������+_��m'�ya>#��H�bP��������a ���+�($m\/�I���va�ee�������K-����N�m�q�=�����Y�~:�t��%���T������*v�T�k�����c�������A1(
��� ����i��X�`!�&,�x����`��J�'kl���q�E)q��Y���8��Jr�*�
%
��^UC��R�3p��x��)�A:z)E)���Q��"�:�qB�`����=Y��]*�����������k��!��P�t�F3&+������N!��"�ZK!5�j�<������������`D���o�#%�c�\�	_ }���A����<��d���UB����Dt�p���[K����n���Y�,���I��rIz�<EY���Da��y]��:)��4)�:s"�g�������0�{�c	a��`V�}9�����N!yt69����c���'uK	�k������6Ne�)��a��}���X��?�~)Y/��>+��1��5�����t��zu>�4��������Ijm��S?��A���4��~E6�_+���k9H'q�� ����-\~w��X�/�c���y���H��+��b�����Yb��\az���u�a�Mv�Z9���YN$���Y:]�B1�;��q�*���h��W��3fb�g${�{+4��wu_�-�{T�r�!r�87���KJ2�����75xS�X�����9~{bl���Q��Pz7�R�C�U������q�p��4k���Z���[-XM|`��4h��/?K��gi8yV��)��Z;��6�p��#����`3���z���8���k�d�����F�.����d�&7Y|��7Y|��7Fj�`�lg��"ug��[GUpdi���oq��N���Z��ZG����5����.�~�BA��b�{x)$�mkI�Np~���pW�Q�y��b:��]B�~�B�=[�5&d-�*ZyA�Ey Nei6���y��������'�50�^�^a����P����������3f�e����mY[�����)�H�/nFi��$�]w��Gc�w6����D�6�&2���>y����B>��������U�,�:oB�,Q���&�_Qc+�&�Q�@��<t�N���E�o
0004-JSON_TABLE-PLAN-clause-v49.patch.gzapplication/gzip; name=0004-JSON_TABLE-PLAN-clause-v49.patch.gzDownload
#53Erik Rijkers
er@xs4all.nl
In reply to: Andrew Dunstan (#52)
1 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 5/18/21 9:23 PM, Andrew Dunstan wrote:

On 5/8/21 2:23 PM, Andrew Dunstan wrote:

On 4/12/21 11:34 AM, Erik Rijkers wrote:

On 2021.03.27. 02:12 Nikita Glukhov <n.gluhov@postgrespro.ru> wrote:
Attached 47th version of the patches.

We're past feature freeze for 14 and alas, JSON_TABLE has not made it.

I have tested quite a bit with it and because I didn't find any trouble with functionality or speed, I wanted to at least mention that here once.

I looked at v47, these files

[0001-SQL-JSON-functions-v47.patch]
[0002-JSON_TABLE-v47.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v47.patch]
[0004-JSON_TABLE-PLAN-clause-v47.patch]
[manual_addition_fixed.patch] # for this see [1], [2]

(v47 doesn't apply anymore, as cfbot shows, but instances can still be built on top of 6131ffc43ff from 30 march 2021)

I hope it will fare better next round, version 15.

Me too. Here's a set that should remove the bitrot.

Rebased for removal of serial schedule

Can one of you please add or integrate this patch to the JSON_TABLE changes?

It contains the fix for a bug that I reported earlier (on 2021-03-30 see
[1]: /messages/by-id/2101814418.20240.1617123418368@webmailclassic.xs4all.nl
included in the latest version, v49.

Thanks,

Erik Rijkers

[1]: /messages/by-id/2101814418.20240.1617123418368@webmailclassic.xs4all.nl
/messages/by-id/2101814418.20240.1617123418368@webmailclassic.xs4all.nl

Show quoted text

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

manual_addition_fixed.patchtext/x-patch; charset=UTF-8; name=manual_addition_fixed.patchDownload
--- src/backend/jit/llvm/llvmjit_types.c.orig	2021-03-30 23:05:01.974817622 +0200
+++ src/backend/jit/llvm/llvmjit_types.c	2021-03-30 23:06:39.080369545 +0200
@@ -130,6 +130,9 @@
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
#54Erik Rijkers
er@xs4all.nl
In reply to: Erik Rijkers (#53)
6 attachment(s)
Re: SQL/JSON: JSON_TABLE

Hi

Here are the 4 unchanged patches from v49, to which I added 2 patches,
which are small changes wrt usage of 'JsonIs' versus 'IsJson'.

That should make the cfbot green again.

Erik Rijkers

Attachments:

0001-SQL-JSON-functions-v49.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-v49.patchDownload
From 64be18ddbaaf0b11b0881839f1b19e1541c2242e Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 8 May 2021 12:08:15 -0400
Subject: [PATCH 1/4] SQL/JSON functions

Common SQL/JSON clauses
SQL/JSON constructors
IS JSON predicate
SQL/JSON query functions
SQL/JSON functions for json type
GUC sql_json
---
 doc/src/sgml/config.sgml                      |   19 +
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  767 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1471 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    9 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  352 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  259 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  437 +++-
 src/backend/utils/misc/guc.c                  |   19 +
 src/backend/utils/misc/postgresql.conf.sample |    1 +
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   47 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb.out           |  130 ++
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1352 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb.sql                |   38 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  467 ++++
 58 files changed, 13150 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 7e32b0686c..daaae626f1 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -9405,6 +9405,25 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir'
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-sql-json" xreflabel="sql_json">
+      <term><varname>sql_json</varname> (<type>enum</type>)
+      <indexterm><primary>json</primary></indexterm>
+      <indexterm><primary>jsonb</primary></indexterm>
+      <indexterm>
+       <primary><varname>sql_json</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+         Valid values are <literal>json</literal> and <literal>jsonb</literal>.
+         Specifies what <productname>PostgreSQL</productname> type is used
+         as an implementation of SQL type <type>JSON</type>.
+         When <varname>sql_json</varname> is set to <literal>jsonb</literal>,
+         <productname>PostgreSQL</productname> type <type>json</type> can be
+         accessed using explicit qualification <type>pg_catalog.json</type>.
+       </para>
+      </listitem>
+     </varlistentry>
      </variablelist>
     </sect2>
    </sect1>
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 3a21129021..77718b4fcc 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17138,6 +17138,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19508,6 +21426,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 8c9f8a6aeb..6d171b34b1 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2412,6 +2412,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					Value	   *argname = (Value *) lfirst(argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->val.str);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 5483dee650..742192d67f 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3887,6 +3919,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4373,3 +4490,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index 8a4075bdaf..fcc53c7e12 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalIsJsonPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 90770a89b0..5716f23152 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2302,6 +2302,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5286,6 +5653,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index ce76d093dd..acc0325786 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -828,6 +828,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3290,6 +3526,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3853,6 +4122,30 @@ equal(const void *a, const void *b)
 		case T_PartitionCmd:
 			retval = _equalPartitionCmd(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 01c110cd2f..ca374dcb29 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -815,3 +816,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ff3dcc7b18..ae1eb505bc 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2328,6 +2436,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2658,6 +2838,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3267,6 +3448,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -3975,6 +4251,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 8da8b14f0e..1183ab8b12 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1740,6 +1740,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4504,6 +4618,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3772ea07df..03e7d0ca9a 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1390,6 +1390,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2972,6 +3131,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 8577c7b138..9720d9d022 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4543,7 +4543,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index e117ab976e..86684637b8 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -49,6 +50,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -377,6 +381,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -848,6 +891,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3459,6 +3514,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index aaf1a51f68..b5f1fe1189 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -62,6 +62,7 @@
 #include "storage/lmgr.h"
 #include "utils/date.h"
 #include "utils/datetime.h"
+#include "utils/jsonb.h"
 #include "utils/numeric.h"
 #include "utils/xml.h"
 
@@ -260,6 +261,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct SelectLimit	*selectlimit;
 	SetQuantifier	 setquantifier;
 	struct GroupClause  *groupclause;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -535,7 +543,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -611,6 +619,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <str>	optColumnCompression
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -636,7 +711,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -646,7 +721,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -657,12 +732,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -673,9 +748,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -688,7 +764,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -696,17 +772,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -714,7 +790,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -739,7 +815,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -757,6 +833,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -792,11 +869,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -814,6 +895,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -12850,6 +12934,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -12868,6 +12953,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13161,7 +13247,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13236,6 +13322,14 @@ interval_second:
 				}
 		;
 
+/* Mapping of PG jsonb types to SQL/JSON JSON type */
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName(SQLJSON_TYPE_NAME());
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13692,6 +13786,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13774,6 +13908,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14026,6 +14179,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14039,6 +14201,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14326,6 +14489,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15024,6 +15189,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15490,6 +16179,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15530,6 +16220,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15566,10 +16257,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15586,6 +16279,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15617,7 +16311,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15660,6 +16356,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15689,6 +16386,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15718,6 +16416,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15769,6 +16468,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -15826,6 +16526,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -15893,6 +16603,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -15994,6 +16705,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16056,6 +16768,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16108,11 +16821,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16133,6 +16848,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16177,7 +16893,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16234,6 +16962,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16270,6 +16999,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16303,6 +17033,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16337,6 +17068,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16370,6 +17102,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 4133526f04..9db8967c60 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index f928c32311..48159d6420 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,8 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +78,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -306,6 +325,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3099,3 +3162,1411 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format = JS_FORMAT_JSONB;
+		}
+		else if (have_json)
+		{
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+		else
+		{
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = SQLJSON_TYPE_OID();
+		JsonFormatType format =
+			SQLJSON_TYPE_IS_JSONB() ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 6e8fbc4780..f390b29637 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1958,6 +1958,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 875de7ba28..683e1ebcfa 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 0e8e065457..0f7646996a 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -23,6 +23,7 @@
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
 #include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/numeric.h"
 #include "utils/syscache.h"
@@ -294,6 +295,14 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "pg_catalog.json" : "json");
+			break;
+
+		case JSONBOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "json" : "jsonb");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index a1145e2721..1f88f8d828 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1018,11 +1018,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6673,3 +6668,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 30ca2cf6c8..3e5bb37369 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index 8d1e7fbf91..d11683c962 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -90,6 +69,8 @@ static JsonbParseState *clone_parse_state(JsonbParseState *state);
 static char *JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool indent);
 static void add_indent(StringInfo out, bool indent, int level);
 
+int			sql_json_type;		/* GUC for mapping jsonb to SQL/JSON JSON */
+
 /*
  * jsonb type input function
  */
@@ -98,7 +79,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +103,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +144,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +242,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +252,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +288,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +611,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1118,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1171,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1182,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1203,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1231,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1269,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
 }
 
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
+}
+
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1553,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1566,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1615,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1687,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1737,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1753,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1773,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1811,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1875,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1957,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2225,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 5711187795..a4117617d4 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -63,7 +63,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -688,7 +689,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -731,6 +734,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1935,7 +1941,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1945,15 +1951,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 09fcff6729..09c1cc7875 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2769,11 +2769,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3245,6 +3245,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5636,3 +5680,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index fa22546f22..fc74cc9e11 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,260 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						Value	   *varname = lfirst(lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						Assert(IsA(varname, String));
+
+						if (strncmp(varname->val.str, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 078aaef539..3b596be9fa 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 84ad62caea..de195d1921 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -63,6 +63,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/hsearch.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
@@ -453,6 +454,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -486,6 +493,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6135,7 +6144,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -7976,6 +7986,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8069,6 +8081,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8092,6 +8105,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8147,6 +8161,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8253,6 +8272,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9428,6 +9562,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((Value *) lfirst(lc1))->val.str);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9525,6 +9763,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9670,17 +9909,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == SQLJSON_TYPE_OID()))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9710,13 +10033,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9752,7 +10076,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9766,6 +10100,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9775,6 +10112,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9794,10 +10141,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9821,16 +10170,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9867,6 +10230,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10107,6 +10479,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index ee731044b6..b7c2dd6f58 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -95,6 +95,7 @@
 #include "utils/bytea.h"
 #include "utils/float.h"
 #include "utils/guc_tables.h"
+#include "utils/jsonb.h"
 #include "utils/memutils.h"
 #include "utils/pg_locale.h"
 #include "utils/pg_lsn.h"
@@ -540,6 +541,12 @@ static struct config_enum_entry default_toast_compression_options[] = {
 	{NULL, 0, false}
 };
 
+const struct config_enum_entry sql_json_type_info[] = {
+	{"json", SQLJSON_TYPE_JSON, false},
+	{"jsonb", SQLJSON_TYPE_JSONB, false},
+	{NULL, 0, false}
+};
+
 /*
  * Options for enum values stored in other modules
  */
@@ -4953,6 +4960,18 @@ static struct config_enum ConfigureNamesEnum[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"sql_json", PGC_USERSET, COMPAT_OPTIONS_CLIENT,
+			gettext_noop("Sets what PostgreSQL type to use as an implementaion of SQL JSON type."),
+			gettext_noop("When turned on, jsonb type is mapped to SQL JSON type, "
+						 "json type is mapped to JSON TEXT type.")
+		},
+		&sql_json_type,
+		SQLJSON_TYPE_JSON,
+		sql_json_type_info,
+		NULL, NULL, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, 0, NULL, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 6e36e4c2ef..4c5256c187 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -758,6 +758,7 @@
 # - Other Platforms and Clients -
 
 #transform_null_equals = off
+#sql_json = json # jsonb
 
 
 #------------------------------------------------------------------------------
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 9f2cd1f127..441902d01f 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(castNode(Value, temp)->val.str);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index fc6d3bfd94..aaf6e20e0b 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -561,14 +561,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index acbcae4607..21ca0c5099 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8659,6 +8659,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8666,10 +8670,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8678,6 +8698,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9550,6 +9583,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9558,10 +9595,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9570,6 +9626,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 785600d04d..a8a2771ba5 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -667,6 +671,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -761,6 +831,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -768,6 +839,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 3dc03c913e..09e3cde548 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 48a7ebfe45..3f55d4b7fb 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index d9e417bcd7..9308049a17 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -202,6 +202,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -491,6 +501,20 @@ typedef enum NodeTag
 	T_PartitionRangeDatum,
 	T_PartitionCmd,
 	T_VacuumRelation,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ef73342019..7ab56d4078 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1538,6 +1538,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 9ae851d847..417cebf4e0 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1225,6 +1225,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format;		/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f836acf876..458f55fbec 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 93f979f320..c20a6a6d5f 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 7daf09f20e..f16cfdcb71 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4e07debf78..be5cc0e397 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,36 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
+
+/* values for the sql+json_type GUC. */
+typedef enum SqlJsonType
+{
+	SQLJSON_TYPE_JSON = 0,
+	SQLJSON_TYPE_JSONB = 1
+} SqlJsonType;
+
+#define SQLJSON_TYPE_IS_JSONB() (sql_json_type == SQLJSON_TYPE_JSONB)
+#define SQLJSON_TYPE_OID() (SQLJSON_TYPE_IS_JSONB() ? JSONBOID : JSONOID)
+#define SQLJSON_TYPE_NAME() (SQLJSON_TYPE_IS_JSONB() ? "jsonb" : "json")
+
+/* GUC */
+extern int sql_json_type;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +433,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +448,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 0ca48591d0..9e9128e8b2 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 87d302b702..fd2663c22f 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index 1e24801a6f..5a8c2f3eef 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a8571a3ffa..c47dee05cb 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb.out b/src/test/regress/expected/jsonb.out
index 1add673968..0ec940ad60 100644
--- a/src/test/regress/expected/jsonb.out
+++ b/src/test/regress/expected/jsonb.out
@@ -5509,3 +5509,133 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
  12345
 (1 row)
 
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+        Table "public.test_json_as_json"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | json  |           |          | 
+ jb     | jsonb |           |          | 
+
+set sql_json = jsonb;
+select json(' { "aa": 1, "b" : 2 }');
+       json        
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+       jsonb       
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+\d test_json_as_json
+             Table "public.test_json_as_json"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | pg_catalog.json |           |          | 
+ jb     | json            |           |          | 
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+             Table "public.test_json_as_jsonb"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | json            |           |          | 
+ jb     | json            |           |          | 
+ jt     | pg_catalog.json |           |          | 
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(pg_catalog.json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
+set sql_json = json;
+\d test_json_as_jsonb
+        Table "public.test_json_as_jsonb"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | jsonb |           |          | 
+ jb     | jsonb |           |          | 
+ jt     | json  |           |          | 
+
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..f2f5e271b8
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 562b586d8e..e7d6358a25 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..51bd216120
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1352 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Result
+   Output: JSON('123'::pg_catalog.json RETURNING pg_catalog.json)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+    pg_typeof    
+-----------------
+ pg_catalog.json
+(1 row)
+
+SET sql_json = json;
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING pg_catalog.json)
+(2 rows)
+
+SET sql_json = json;
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 22b0d3584d..fb721b5e54 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -108,7 +108,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb.sql b/src/test/regress/sql/jsonb.sql
index 5016f29c15..4af2a0cb11 100644
--- a/src/test/regress/sql/jsonb.sql
+++ b/src/test/regress/sql/jsonb.sql
@@ -1482,3 +1482,41 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
+
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+
+set sql_json = jsonb;
+
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+\d test_json_as_json
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+
+set sql_json = json;
+\d test_json_as_jsonb
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 5a9c479692..7a849ae363 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..4ff6076763
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,467 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+
+SET sql_json = json;
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+
+SET sql_json = json;
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.4

0002-JSON_TABLE-v49.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v49.patchDownload
From 869652c78ddec8a5083f1a44eb096be4ab78df14 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 8 May 2021 12:24:02 -0400
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  19 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  10 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 467 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 227 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  37 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2885 insertions(+), 32 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 77718b4fcc..89be011c47 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18206,6 +18206,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -18876,6 +18881,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 9a60865d19..78b053a0d5 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3790,7 +3790,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 6d171b34b1..30a7298ecb 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2619,6 +2619,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 742192d67f..4bd1849a5e 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4595,6 +4595,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4687,8 +4688,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4824,6 +4831,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	/* Want to execute expressions inside function's memory context */
 	MemoryContextSwitchTo(oldcontext);
 
+
 	PG_TRY();
 	{
 		res = func(op, econtext, res, resnull, p, error);
@@ -4836,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4847,8 +4856,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4974,6 +4985,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 4d7eca4ace..fd10d110af 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 5716f23152..6c90dda16e 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1398,6 +1398,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1408,7 +1409,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2669,6 +2672,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5719,6 +5792,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index acc0325786..04577ba996 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -120,6 +120,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -130,13 +131,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3559,6 +3582,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ae1eb505bc..9bfee2ed38 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2434,6 +2434,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3445,6 +3447,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4402,6 +4405,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 1183ab8b12..7107b83385 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1081,6 +1081,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1091,7 +1092,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1854,6 +1857,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4645,6 +4668,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 03e7d0ca9a..58cec783bd 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -535,6 +535,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -545,7 +546,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1495,6 +1498,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3149,6 +3176,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index b5f1fe1189..5cad551434 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -646,15 +646,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -668,6 +678,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -675,6 +686,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -749,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -759,8 +772,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -768,7 +781,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -870,7 +883,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -895,6 +908,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12290,6 +12307,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12834,6 +12864,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15361,6 +15393,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15475,6 +15511,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16339,6 +16522,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16372,6 +16556,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16535,6 +16720,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -16902,6 +17088,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -16939,6 +17126,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16982,6 +17170,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 89d95d3e94..b59d56db63 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -697,7 +697,7 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1101,13 +1101,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 48159d6420..d55b5ecaae 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4097,7 +4097,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4135,14 +4135,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4443,6 +4442,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..38fd99915b
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,467 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  pasring of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 7465919044..a9b75aa774 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index f390b29637..26143f973d 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1993,6 +1993,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 3b596be9fa..d4a9a76808 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->val.str);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index de195d1921..5d151d2bc1 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -495,6 +495,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8362,7 +8364,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9625,6 +9628,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10873,16 +10879,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10973,6 +10977,219 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 441902d01f..4e9fe6d523 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index a8a2771ba5..9b8959300e 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -849,6 +849,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 9308049a17..b3a5559ee9 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -212,6 +212,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -510,6 +512,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 7ab56d4078..d819e58e82 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1551,6 +1551,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1610,6 +1623,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 417cebf4e0..acd6c2505b 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1233,7 +1242,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1447,6 +1457,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 458f55fbec..15f586d455 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 0eab3c03e8..9216f81acb 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index fd2663c22f..3c37ea087a 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index f2f5e271b8..d89c3bef44 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..6614dd6e45 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index abdb08319c..d88c612bee 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1227,6 +1227,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2608,6 +2616,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.4

0003-JSON_TABLE-PLAN-DEFAULT-clause-v49.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v49.patchDownload
From cc45bd9a36354c6c04d2a4b2b95b2a6b9929a441 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 8 May 2021 12:38:30 -0400
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |  11 +-
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 463 insertions(+), 54 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 89be011c47..2103b39db7 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18889,6 +18889,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -18950,7 +18954,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -18963,22 +18968,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parrent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19150,6 +19139,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19172,8 +19165,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 6c90dda16e..be2e06d93d 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2684,6 +2684,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2722,6 +2723,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2738,6 +2741,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 04577ba996..4a04e8ad69 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -145,6 +145,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -156,6 +158,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 7107b83385..9d111b9b92 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1864,6 +1864,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1875,6 +1877,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 58cec783bd..dbabb8bfc5 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1505,6 +1505,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1518,6 +1520,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 5cad551434..12c5b76888 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -668,6 +668,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -781,7 +786,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15515,13 +15520,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15658,6 +15665,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16557,6 +16592,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17172,6 +17208,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 38fd99915b..6ceafaa2d8 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -174,12 +174,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -187,7 +188,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -195,8 +196,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -208,7 +210,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -386,6 +388,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index d4a9a76808..71d62125e4 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 5d151d2bc1..68c103936b 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11157,7 +11157,7 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 			get_rule_expr((Node *) lfirst(lc2), context, false);
 			appendStringInfo(buf, " AS %s",
-							 quote_identifier(((Value *) lfirst(lc1))->val.str));
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
 		}
 
 		if (PRETTY_INDENT(context))
@@ -11166,6 +11166,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d819e58e82..1c10e55a37 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1643,6 +1643,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1652,6 +1664,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index acd6c2505b..3edc30a09e 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1466,6 +1466,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1480,6 +1482,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 15f586d455..6065bbae88 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index d89c3bef44..0cd8f73c66 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 6614dd6e45..cd97ff7f46 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index d88c612bee..8e98988cd0 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1233,6 +1233,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.4

0004-JSON_TABLE-PLAN-clause-v49.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v49.patchDownload
From 3676e298eaeba4e607a9e050b68129c259068af7 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 8 May 2021 14:10:23 -0400
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 322 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1389 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 2103b39db7..8aba396c88 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18887,9 +18887,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -18913,6 +18914,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -18955,7 +18966,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19140,7 +19151,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19167,18 +19178,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19257,6 +19281,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19288,9 +19329,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index be2e06d93d..df38772c10 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2682,9 +2682,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2702,6 +2702,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2713,6 +2714,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2722,9 +2741,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5802,6 +5821,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 4a04e8ad69..7777b26ee2 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -144,9 +144,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ca374dcb29..46d7f61e25 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -864,6 +864,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 9d111b9b92..0d50474ce8 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1863,9 +1863,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index dbabb8bfc5..3b36ab3455 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1504,9 +1504,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 12c5b76888..f3a2099cae 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -653,6 +653,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -668,8 +680,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15527,7 +15537,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15649,12 +15659,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15666,12 +15679,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 6ceafaa2d8..ecb169da14 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -38,12 +38,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -156,19 +159,154 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -186,34 +324,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -377,19 +559,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -407,7 +650,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -415,9 +660,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -453,7 +720,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 68c103936b..16d6c29ff7 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11003,10 +11003,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11135,6 +11179,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11166,14 +11212,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 3f55d4b7fb..405547bad6 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1c10e55a37..ca6b96cbba 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1634,6 +1634,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1643,6 +1644,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1655,6 +1667,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1664,7 +1693,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 3edc30a09e..0dd9df21f4 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1465,9 +1465,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0cd8f73c66..81f94e3c91 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE path names and column names shall be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index cd97ff7f46..be2d65b3ff 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 8e98988cd0..f1927a2bd6 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1233,7 +1233,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.4

v49-fix-llvmjit_expr.difftext/x-patch; charset=UTF-8; name=v49-fix-llvmjit_expr.diffDownload
--- ./src/backend/jit/llvm/llvmjit_expr.c.orig2	2021-07-21 14:03:40.964827001 +0200
+++ ./src/backend/jit/llvm/llvmjit_expr.c	2021-07-21 14:04:06.709273766 +0200
@@ -2355,7 +2355,7 @@
 				break;
 
 			case EEOP_IS_JSON:
-				build_EvalXFunc(b, mod, "ExecEvalIsJsonPredicate",
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
 								v_state, op);
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
v49-fix-llvmjit_types.difftext/x-patch; charset=UTF-8; name=v49-fix-llvmjit_types.diffDownload
--- src/backend/jit/llvm/llvmjit_types.c.orig	2021-07-21 14:05:51.939098249 +0200
+++ src/backend/jit/llvm/llvmjit_types.c	2021-07-21 14:06:51.556130847 +0200
@@ -131,6 +131,9 @@
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
#55Daniel Gustafsson
daniel@yesql.se
In reply to: Andrew Dunstan (#52)
Re: SQL/JSON: JSON_TABLE

Below are a few small comments from a casual read-through. I noticed that
there was a new version posted after I had finished perusing, but it seems to
address other aspects.

+ Gerenates a column and inserts a composite SQL/JSON
s/Gerenates/Generates/

+ into both child and parrent columns for all missing values.
s/parrent/parent/

-         objectname = "xmltable";
+         objectname = rte->tablefunc ?
+                 rte->tablefunc->functype == TFT_XMLTABLE ?
+                 "xmltable" : "json_table" : NULL;
In which case can rte->tablefunc be NULL for a T_TableFuncScan?  Also, nested
ternary operators are confusing at best, I think this should be rewritten as
plain if statements.

In general when inspecting functype I think it's better to spell it out with if
statements rather than ternary since it allows for grepping the code easier.
Having to grep for TFT_XMLTABLE to find json_table isn't all that convenient.
That also removes the need for comments stating why a ternary operator is Ok in
the first place.

+ errmsg("JSON_TABLE() is not yet implemented for json type"),
I can see this being potentially confusing to many, en errhint with a reference
to jsonb seems like a good idea.

+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
This comment is misleading since the function isn't actually recursive, but a
helper function for a recursive function.
+        switch (get_typtype(typid))
+        {
+                case TYPTYPE_COMPOSITE:
+                        return true;
+
+                case TYPTYPE_DOMAIN:
+                        return typeIsComposite(getBaseType(typid));
+        }
switch statements without a default runs the risk of attracting unwanted
compiler warning attention, or make static analyzers angry.  This one can
easily be rewritten with two if-statements on a cached get_typtype()
returnvalue.

+ * Returned false at the end of a scan, true otherwise.
s/Returned/Returns/ (applies at two places)

+ /* state->ordinal--; */ /* skip current outer row, reset counter */
Is this dead code to be removed, or left in there as a reminder to fix
something?

--
Daniel Gustafsson https://vmware.com/

#56Andrew Dunstan
andrew@dunslane.net
In reply to: Erik Rijkers (#54)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 7/22/21 3:49 AM, Erik Rijkers wrote:

Hi

Here are the 4 unchanged patches from v49, to which I added 2 patches,
which are small changes wrt usage of  'JsonIs'  versus  'IsJson'.

That should make the cfbot green again.

Apparently not, but I have rebased this and the sql/json function patch
set and incorporated your changes in both.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-v50.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-v50.patchDownload
From 969968cc6071aa2932c26a7d29946d66794d7177 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 2 Sep 2021 13:54:48 -0400
Subject: [PATCH 1/4] SQL/JSON functions

Common SQL/JSON clauses
SQL/JSON constructors
IS JSON predicate
SQL/JSON query functions
SQL/JSON functions for json type
GUC sql_json
---
 doc/src/sgml/config.sgml                      |   19 +
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  767 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1471 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    9 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  352 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  259 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  437 +++-
 src/backend/utils/misc/guc.c                  |   19 +
 src/backend/utils/misc/postgresql.conf.sample |    1 +
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   47 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb.out           |  130 ++
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1352 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb.sql                |   38 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  467 ++++
 59 files changed, 13153 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 2c31c35a6b..a0b2d185c8 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -9500,6 +9500,25 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir'
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-sql-json" xreflabel="sql_json">
+      <term><varname>sql_json</varname> (<type>enum</type>)
+      <indexterm><primary>json</primary></indexterm>
+      <indexterm><primary>jsonb</primary></indexterm>
+      <indexterm>
+       <primary><varname>sql_json</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+         Valid values are <literal>json</literal> and <literal>jsonb</literal>.
+         Specifies what <productname>PostgreSQL</productname> type is used
+         as an implementation of SQL type <type>JSON</type>.
+         When <varname>sql_json</varname> is set to <literal>jsonb</literal>,
+         <productname>PostgreSQL</productname> type <type>json</type> can be
+         accessed using explicit qualification <type>pg_catalog.json</type>.
+       </para>
+      </listitem>
+     </varlistentry>
      </variablelist>
     </sect2>
    </sect1>
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 78812b2dbe..a75b92bdb9 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17456,6 +17456,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19596,6 +21514,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 81b9d87bad..3f190e06a6 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					Value	   *argname = (Value *) lfirst(argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->val.str);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index eb49817cee..0d4d30853e 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4386,3 +4503,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index 6d1181225e..15c9ee44c0 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index 2deb65c5b5..b507d98ca1 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 38251c2b8e..4b53cfa869 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2291,6 +2291,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5278,6 +5645,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 8a1762000c..4348e15fa9 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -834,6 +834,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3299,6 +3535,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3862,6 +4131,30 @@ equal(const void *a, const void *b)
 		case T_PartitionCmd:
 			retval = _equalPartitionCmd(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 01c110cd2f..ca374dcb29 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -815,3 +816,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ff3dcc7b18..ae1eb505bc 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2328,6 +2436,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2658,6 +2838,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3267,6 +3448,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -3975,6 +4251,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 87561cbb6f..2fb107f3ad 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1741,6 +1741,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4520,6 +4634,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 0dd1ad7dfc..cbffe4695e 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1391,6 +1391,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2973,6 +3132,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 1fd53b40bb..a412014e12 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4540,7 +4540,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index 3412d31117..c1951c1caf 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -381,6 +385,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -852,6 +895,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3511,6 +3566,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 39a2849eba..465f815154 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -62,6 +62,7 @@
 #include "storage/lmgr.h"
 #include "utils/date.h"
 #include "utils/datetime.h"
+#include "utils/jsonb.h"
 #include "utils/numeric.h"
 #include "utils/xml.h"
 
@@ -260,6 +261,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct SelectLimit	*selectlimit;
 	SetQuantifier	 setquantifier;
 	struct GroupClause  *groupclause;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -535,7 +543,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -611,6 +619,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -636,7 +711,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -646,7 +721,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -657,12 +732,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -673,9 +748,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -688,7 +764,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -696,17 +772,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -714,7 +790,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -739,7 +815,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -757,6 +833,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -792,11 +869,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -814,6 +895,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -12836,6 +12920,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -12854,6 +12939,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13147,7 +13233,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13222,6 +13308,14 @@ interval_second:
 				}
 		;
 
+/* Mapping of PG jsonb types to SQL/JSON JSON type */
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName(SQLJSON_TYPE_NAME());
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13678,6 +13772,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13760,6 +13894,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14012,6 +14165,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14025,6 +14187,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14312,6 +14475,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15010,6 +15175,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15476,6 +16165,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15516,6 +16206,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15552,10 +16243,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15572,6 +16265,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15603,7 +16297,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15646,6 +16342,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15675,6 +16372,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15704,6 +16402,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15755,6 +16454,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -15812,6 +16512,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -15879,6 +16589,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -15980,6 +16691,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16042,6 +16754,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16094,11 +16807,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16119,6 +16834,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16163,7 +16879,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16220,6 +16948,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16256,6 +16985,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16289,6 +17019,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16323,6 +17054,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16356,6 +17088,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 4133526f04..9db8967c60 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index f928c32311..48159d6420 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,8 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +78,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -306,6 +325,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3099,3 +3162,1411 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format = JS_FORMAT_JSONB;
+		}
+		else if (have_json)
+		{
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+		else
+		{
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = SQLJSON_TYPE_OID();
+		JsonFormatType format =
+			SQLJSON_TYPE_IS_JSONB() ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 6e8fbc4780..f390b29637 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1958,6 +1958,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 875de7ba28..683e1ebcfa 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 0e8e065457..0f7646996a 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -23,6 +23,7 @@
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
 #include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/numeric.h"
 #include "utils/syscache.h"
@@ -294,6 +295,14 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "pg_catalog.json" : "json");
+			break;
+
+		case JSONBOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "json" : "jsonb");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index a1145e2721..1f88f8d828 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1018,11 +1018,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6673,3 +6668,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 30ca2cf6c8..3e5bb37369 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index 8d1e7fbf91..d11683c962 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -90,6 +69,8 @@ static JsonbParseState *clone_parse_state(JsonbParseState *state);
 static char *JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool indent);
 static void add_indent(StringInfo out, bool indent, int level);
 
+int			sql_json_type;		/* GUC for mapping jsonb to SQL/JSON JSON */
+
 /*
  * jsonb type input function
  */
@@ -98,7 +79,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +103,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +144,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +242,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +252,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +288,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +611,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1118,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1171,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1182,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1203,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1231,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1269,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
 }
 
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
+}
+
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1553,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1566,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1615,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1687,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1737,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1753,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1773,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1811,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1875,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1957,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2225,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 5711187795..a4117617d4 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -63,7 +63,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -688,7 +689,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -731,6 +734,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1935,7 +1941,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1945,15 +1951,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 5fd54b64b5..fb01f67229 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2771,11 +2771,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3247,6 +3247,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5638,3 +5682,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index fa22546f22..fc74cc9e11 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,260 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						Value	   *varname = lfirst(lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						Assert(IsA(varname, String));
+
+						if (strncmp(varname->val.str, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 078aaef539..3b596be9fa 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 8ff4e5dc07..b41cc06731 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -63,6 +63,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/hsearch.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
@@ -453,6 +454,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -486,6 +493,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6151,7 +6160,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -7992,6 +8002,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8085,6 +8097,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8108,6 +8121,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8163,6 +8177,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8269,6 +8288,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9444,6 +9578,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((Value *) lfirst(lc1))->val.str);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9541,6 +9779,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9686,17 +9925,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == SQLJSON_TYPE_OID()))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9726,13 +10049,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9768,7 +10092,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9782,6 +10116,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9791,6 +10128,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9810,10 +10157,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9837,16 +10186,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9883,6 +10246,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10123,6 +10495,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index 467b0fd6fe..6f226ca13a 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -95,6 +95,7 @@
 #include "utils/bytea.h"
 #include "utils/float.h"
 #include "utils/guc_tables.h"
+#include "utils/jsonb.h"
 #include "utils/memutils.h"
 #include "utils/pg_locale.h"
 #include "utils/pg_lsn.h"
@@ -556,6 +557,12 @@ static const struct config_enum_entry wal_compression_options[] = {
 	{NULL, 0, false}
 };
 
+const struct config_enum_entry sql_json_type_info[] = {
+	{"json", SQLJSON_TYPE_JSON, false},
+	{"jsonb", SQLJSON_TYPE_JSONB, false},
+	{NULL, 0, false}
+};
+
 /*
  * Options for enum values stored in other modules
  */
@@ -4970,6 +4977,18 @@ static struct config_enum ConfigureNamesEnum[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"sql_json", PGC_USERSET, COMPAT_OPTIONS_CLIENT,
+			gettext_noop("Sets what PostgreSQL type to use as an implementaion of SQL JSON type."),
+			gettext_noop("When turned on, jsonb type is mapped to SQL JSON type, "
+						 "json type is mapped to JSON TEXT type.")
+		},
+		&sql_json_type,
+		SQLJSON_TYPE_JSON,
+		sql_json_type_info,
+		NULL, NULL, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, 0, NULL, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 3fe9a53cb3..3292846f89 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -762,6 +762,7 @@
 # - Other Platforms and Clients -
 
 #transform_null_equals = off
+#sql_json = json # jsonb
 
 
 #------------------------------------------------------------------------------
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 9f2cd1f127..441902d01f 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(castNode(Value, temp)->val.str);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index fc6d3bfd94..aaf6e20e0b 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -561,14 +561,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 1a750a49ca..07e31225f4 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8722,6 +8722,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8729,10 +8733,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8741,6 +8761,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9613,6 +9646,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9621,10 +9658,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9633,6 +9689,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 6a24341faa..00916724d9 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 3dc03c913e..09e3cde548 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 48a7ebfe45..3f55d4b7fb 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 6a4d82f0a8..4ef0a04069 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -202,6 +202,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -490,6 +500,20 @@ typedef enum NodeTag
 	T_PartitionRangeDatum,
 	T_PartitionCmd,
 	T_VacuumRelation,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 7af13dee43..edd4d3ca0f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1538,6 +1538,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index c04282f91f..43e6987738 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1235,6 +1235,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format;		/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f836acf876..458f55fbec 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 93f979f320..c20a6a6d5f 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 7daf09f20e..f16cfdcb71 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4e07debf78..be5cc0e397 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,36 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
+
+/* values for the sql+json_type GUC. */
+typedef enum SqlJsonType
+{
+	SQLJSON_TYPE_JSON = 0,
+	SQLJSON_TYPE_JSONB = 1
+} SqlJsonType;
+
+#define SQLJSON_TYPE_IS_JSONB() (sql_json_type == SQLJSON_TYPE_JSONB)
+#define SQLJSON_TYPE_OID() (SQLJSON_TYPE_IS_JSONB() ? JSONBOID : JSONOID)
+#define SQLJSON_TYPE_NAME() (SQLJSON_TYPE_IS_JSONB() ? "jsonb" : "json")
+
+/* GUC */
+extern int sql_json_type;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +433,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +448,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 0ca48591d0..9e9128e8b2 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 87d302b702..fd2663c22f 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index 1e24801a6f..5a8c2f3eef 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a8571a3ffa..c47dee05cb 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb.out b/src/test/regress/expected/jsonb.out
index 1add673968..0ec940ad60 100644
--- a/src/test/regress/expected/jsonb.out
+++ b/src/test/regress/expected/jsonb.out
@@ -5509,3 +5509,133 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
  12345
 (1 row)
 
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+        Table "public.test_json_as_json"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | json  |           |          | 
+ jb     | jsonb |           |          | 
+
+set sql_json = jsonb;
+select json(' { "aa": 1, "b" : 2 }');
+       json        
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+       jsonb       
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+\d test_json_as_json
+             Table "public.test_json_as_json"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | pg_catalog.json |           |          | 
+ jb     | json            |           |          | 
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+             Table "public.test_json_as_jsonb"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | json            |           |          | 
+ jb     | json            |           |          | 
+ jt     | pg_catalog.json |           |          | 
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(pg_catalog.json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
+set sql_json = json;
+\d test_json_as_jsonb
+        Table "public.test_json_as_jsonb"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | jsonb |           |          | 
+ jb     | jsonb |           |          | 
+ jt     | json  |           |          | 
+
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..f2f5e271b8
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 562b586d8e..e7d6358a25 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..51bd216120
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1352 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Result
+   Output: JSON('123'::pg_catalog.json RETURNING pg_catalog.json)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+    pg_typeof    
+-----------------
+ pg_catalog.json
+(1 row)
+
+SET sql_json = json;
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING pg_catalog.json)
+(2 rows)
+
+SET sql_json = json;
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 7be89178f0..810450164d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -108,7 +108,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb.sql b/src/test/regress/sql/jsonb.sql
index 5016f29c15..4af2a0cb11 100644
--- a/src/test/regress/sql/jsonb.sql
+++ b/src/test/regress/sql/jsonb.sql
@@ -1482,3 +1482,41 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
+
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+
+set sql_json = jsonb;
+
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+\d test_json_as_json
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+
+set sql_json = json;
+\d test_json_as_jsonb
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 5a9c479692..7a849ae363 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..4ff6076763
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,467 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+
+SET sql_json = json;
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+
+SET sql_json = json;
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.4

0002-JSON_TABLE-v50.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v50.patchDownload
From c23d07af81dc035d46c456797e71978bea9c7e3f Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 2 Sep 2021 14:00:41 -0400
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  19 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  10 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 467 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 227 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  37 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2885 insertions(+), 32 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index a75b92bdb9..e86c8992c3 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18524,6 +18524,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19194,6 +19199,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 10644dfac4..9ba9eb6d27 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3784,7 +3784,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 3f190e06a6..e6638d226d 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0d4d30853e..3be81abc91 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4608,6 +4608,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4700,8 +4701,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4837,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	/* Want to execute expressions inside function's memory context */
 	MemoryContextSwitchTo(oldcontext);
 
+
 	PG_TRY();
 	{
 		res = func(op, econtext, res, resnull, p, error);
@@ -4849,6 +4857,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4860,8 +4869,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4987,6 +4998,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 4d7eca4ace..fd10d110af 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 4b53cfa869..4cd67133b9 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1386,6 +1386,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1396,7 +1397,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2658,6 +2661,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5711,6 +5784,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 4348e15fa9..6fbbaf6790 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -120,6 +120,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -130,13 +131,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3568,6 +3591,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ae1eb505bc..9bfee2ed38 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2434,6 +2434,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3445,6 +3447,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4402,6 +4405,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 2fb107f3ad..6563da60d3 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1081,6 +1081,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1091,7 +1092,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1855,6 +1858,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4661,6 +4684,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index cbffe4695e..cc173a38ec 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -535,6 +535,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -545,7 +546,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1496,6 +1499,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3150,6 +3177,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 465f815154..dbef044f25 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -646,15 +646,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -668,6 +678,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -675,6 +686,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -749,7 +762,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -759,8 +772,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -768,7 +781,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -870,7 +883,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -895,6 +908,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12276,6 +12293,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12820,6 +12850,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15347,6 +15379,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15461,6 +15497,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16325,6 +16508,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16358,6 +16542,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16521,6 +16706,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -16888,6 +17074,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -16925,6 +17112,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16968,6 +17156,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index b3f151d33b..6fe3958e3e 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,7 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1100,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 48159d6420..d55b5ecaae 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4097,7 +4097,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4135,14 +4135,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4443,6 +4442,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..38fd99915b
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,467 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  pasring of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.type = T_String;
+	n->val.val.str = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 7465919044..a9b75aa774 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index f390b29637..26143f973d 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1993,6 +1993,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 3b596be9fa..d4a9a76808 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			Value	   *name = (Value *) lfirst(namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->val.str);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b41cc06731..11cb3a91ad 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -495,6 +495,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8378,7 +8380,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9641,6 +9644,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10889,16 +10895,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10989,6 +10993,219 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier(((Value *) lfirst(lc1))->val.str));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 441902d01f..4e9fe6d523 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 00916724d9..0abe9d1ee4 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 4ef0a04069..2c31ebf769 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -212,6 +212,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -509,6 +511,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index edd4d3ca0f..627061e76c 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1551,6 +1551,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1610,6 +1623,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 43e6987738..2549ea6ac4 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1243,7 +1252,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1457,6 +1467,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 458f55fbec..15f586d455 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 0eab3c03e8..9216f81acb 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index fd2663c22f..3c37ea087a 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index f2f5e271b8..d89c3bef44 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..6614dd6e45 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index f31a1e4e1e..daa544ec65 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1231,6 +1231,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2617,6 +2625,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.4

0003-JSON_TABLE-PLAN-DEFAULT-clause-v50.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v50.patchDownload
From 822248a960041b414789e717e4b270c8b2900fc7 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 2 Sep 2021 14:04:35 -0400
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |  11 +-
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 463 insertions(+), 54 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index e86c8992c3..746f24501a 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19207,6 +19207,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19268,7 +19272,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19281,22 +19286,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parrent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19468,6 +19457,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19490,8 +19483,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 4cd67133b9..fcc877b5bf 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2673,6 +2673,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2711,6 +2712,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2727,6 +2730,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 6fbbaf6790..35c6a0f2ea 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -145,6 +145,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -156,6 +158,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 6563da60d3..410e4dacbc 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1865,6 +1865,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1876,6 +1878,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index cc173a38ec..b9f12205b3 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1506,6 +1506,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1519,6 +1521,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index dbef044f25..2ac79c54a8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -668,6 +668,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -781,7 +786,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15501,13 +15506,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15644,6 +15651,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16543,6 +16578,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17158,6 +17194,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 38fd99915b..6ceafaa2d8 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -174,12 +174,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -187,7 +188,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -195,8 +196,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -208,7 +210,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -386,6 +388,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index d4a9a76808..71d62125e4 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 11cb3a91ad..7e68752666 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11173,7 +11173,7 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 			get_rule_expr((Node *) lfirst(lc2), context, false);
 			appendStringInfo(buf, " AS %s",
-							 quote_identifier(((Value *) lfirst(lc1))->val.str));
+					quote_identifier(((Value *) lfirst(lc1))->val.str));
 		}
 
 		if (PRETTY_INDENT(context))
@@ -11182,6 +11182,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 627061e76c..ad270c9f0b 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1643,6 +1643,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1652,6 +1664,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 2549ea6ac4..cfaf967360 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1476,6 +1476,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1490,6 +1492,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 15f586d455..6065bbae88 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index d89c3bef44..0cd8f73c66 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 6614dd6e45..cd97ff7f46 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index daa544ec65..69d3711001 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1237,6 +1237,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.4

0004-JSON_TABLE-PLAN-clause-v50.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v50.patchDownload
From c873ce99ceec281006ac1316f6ae4db058d56c6c Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 2 Sep 2021 14:05:46 -0400
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 322 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1389 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 746f24501a..a660cdf956 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19205,9 +19205,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19231,6 +19232,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19273,7 +19284,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19458,7 +19469,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19485,18 +19496,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19575,6 +19599,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19606,9 +19647,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index fcc877b5bf..0c0e5c74cd 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2671,9 +2671,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2691,6 +2691,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2702,6 +2703,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2711,9 +2730,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5794,6 +5813,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 35c6a0f2ea..b89a3563d3 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -144,9 +144,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ca374dcb29..46d7f61e25 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -864,6 +864,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 410e4dacbc..41c39d69ed 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1864,9 +1864,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index b9f12205b3..d73689ee97 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1505,9 +1505,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 2ac79c54a8..f68b874eed 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -653,6 +653,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -668,8 +680,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15513,7 +15523,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15635,12 +15645,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15652,12 +15665,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 6ceafaa2d8..ecb169da14 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -38,12 +38,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -156,19 +159,154 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -186,34 +324,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -377,19 +559,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -407,7 +650,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -415,9 +660,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -453,7 +720,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.val.str;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 7e68752666..380ec8b472 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11019,10 +11019,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11151,6 +11195,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11182,14 +11228,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 3f55d4b7fb..405547bad6 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ad270c9f0b..8797b01fdf 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1634,6 +1634,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1643,6 +1644,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1655,6 +1667,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1664,7 +1693,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index cfaf967360..c341293cbf 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1475,9 +1475,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0cd8f73c66..81f94e3c91 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE path names and column names shall be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index cd97ff7f46..be2d65b3ff 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 69d3711001..f393c50ab4 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1237,7 +1237,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.4

#57Erik Rijkers
er@xs4all.nl
In reply to: Andrew Dunstan (#56)
Re: SQL/JSON: JSON_TABLE

On 9/2/21 8:52 PM, Andrew Dunstan wrote:

On 7/22/21 3:49 AM, Erik Rijkers wrote:

Hi

Here are the 4 unchanged patches from v49, to which I added 2 patches,
which are small changes wrt usage of  'JsonIs'  versus  'IsJson'.

That should make the cfbot green again.

Apparently not, but I have rebased this and the sql/json function patch
set and incorporated your changes in both.

[0001-SQL-JSON-functions-v50.patch]
[0002-JSON_TABLE-v50.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v50.patch]
[0004-JSON_TABLE-PLAN-clause-v50.patch]

These don't apply any more, could you have a look?

Thanks,

Erik Rijkers

(output from gcc 11.2:)

parse_jsontable.c: In function ‘makeStringConst’:
parse_jsontable.c:57:15: error: ‘union ValUnion’ has no member named ‘type’
57 | n->val.type = T_String;
| ^
parse_jsontable.c:58:16: error: ‘union ValUnion’ has no member named
‘val’; did you mean ‘ival’?
58 | n->val.val.str = str;
| ^~~
| ival
parse_jsontable.c: In function ‘transformJsonTable’:
parse_jsontable.c:714:61: error: ‘union ValUnion’ has no member named ‘type’
714 | castNode(A_Const,
jt->common->pathspec)->val.type != T_String)
| ^
parse_jsontable.c:721:65: error: ‘union ValUnion’ has no member named
‘val’; did you mean ‘ival’?
721 | rootPath = castNode(A_Const,
jt->common->pathspec)->val.val.str;
| ^~~
|
ival
make[3]: *** [parse_jsontable.o] Error 1
make[3]: *** Waiting for unfinished jobs....
make[2]: *** [parser-recursive] Error 2
make[2]: *** Waiting for unfinished jobs....
make[1]: *** [all-backend-recurse] Error 2
make: *** [all-src-recurse] Error 2
../../../src/Makefile.global:938: recipe for target 'parse_jsontable.o'
failed
common.mk:39: recipe for target 'parser-recursive' failed
Makefile:42: recipe for target 'all-backend-recurse' failed
GNUmakefile:11: recipe for target 'all-src-recurse' failed

#58Andrew Dunstan
andrew@dunslane.net
In reply to: Erik Rijkers (#57)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 9/13/21 5:41 AM, Erik Rijkers wrote:

On 9/2/21 8:52 PM, Andrew Dunstan wrote:

On 7/22/21 3:49 AM, Erik Rijkers wrote:

Hi

Here are the 4 unchanged patches from v49, to which I added 2 patches,
which are small changes wrt usage of  'JsonIs'  versus  'IsJson'.

That should make the cfbot green again.

Apparently not, but I have rebased this and the sql/json function patch
set and incorporated your changes in both.

[0001-SQL-JSON-functions-v50.patch]
[0002-JSON_TABLE-v50.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v50.patch]
[0004-JSON_TABLE-PLAN-clause-v50.patch]

These don't apply any more, could you have a look?

Yeah, we ran foul of the removal of the Value node type. Here's a rebase.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-v51.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-v51.patchDownload
From 3af2d71cf60d6c32e7a642c9ae5fa1b756d36c3a Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Mon, 13 Sep 2021 16:55:21 -0400
Subject: [PATCH 1/4] SQL/JSON functions

Common SQL/JSON clauses
SQL/JSON constructors
IS JSON predicate
SQL/JSON query functions
SQL/JSON functions for json type
GUC sql_json
---
 doc/src/sgml/config.sgml                      |   19 +
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  767 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1471 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    9 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  352 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  437 +++-
 src/backend/utils/misc/guc.c                  |   19 +
 src/backend/utils/misc/postgresql.conf.sample |    1 +
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   47 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb.out           |  130 ++
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1352 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb.sql                |   38 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  467 ++++
 59 files changed, 13151 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index ef0e2a7746..1b9a552ec8 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -9500,6 +9500,25 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir'
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-sql-json" xreflabel="sql_json">
+      <term><varname>sql_json</varname> (<type>enum</type>)
+      <indexterm><primary>json</primary></indexterm>
+      <indexterm><primary>jsonb</primary></indexterm>
+      <indexterm>
+       <primary><varname>sql_json</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+         Valid values are <literal>json</literal> and <literal>jsonb</literal>.
+         Specifies what <productname>PostgreSQL</productname> type is used
+         as an implementation of SQL type <type>JSON</type>.
+         When <varname>sql_json</varname> is set to <literal>jsonb</literal>,
+         <productname>PostgreSQL</productname> type <type>json</type> can be
+         accessed using explicit qualification <type>pg_catalog.json</type>.
+       </para>
+      </listitem>
+     </varlistentry>
      </variablelist>
     </sect2>
    </sect1>
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 78812b2dbe..a75b92bdb9 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17456,6 +17456,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19596,6 +21514,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 81b9d87bad..efcfde8c95 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->val);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index eb49817cee..0d4d30853e 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4386,3 +4503,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index 6d1181225e..15c9ee44c0 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index 2deb65c5b5..b507d98ca1 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 228387eaee..ba2eb0f894 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2295,6 +2295,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5306,6 +5673,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 800f588b5c..ffb186825f 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3326,6 +3562,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3897,6 +4166,30 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 01c110cd2f..ca374dcb29 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -815,3 +816,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index e276264882..97bd0bac6b 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2328,6 +2436,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2658,6 +2838,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3267,6 +3448,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -3974,6 +4250,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index f2a6a6e7a0..c3aa51c639 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1748,6 +1748,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4521,6 +4635,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 0dd1ad7dfc..cbffe4695e 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1391,6 +1391,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2973,6 +3132,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 1fd53b40bb..a412014e12 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4540,7 +4540,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index 3412d31117..c1951c1caf 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -381,6 +385,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -852,6 +895,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3511,6 +3566,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index e3068a374e..b70949b122 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -62,6 +62,7 @@
 #include "storage/lmgr.h"
 #include "utils/date.h"
 #include "utils/datetime.h"
+#include "utils/jsonb.h"
 #include "utils/numeric.h"
 #include "utils/xml.h"
 
@@ -259,6 +260,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct SelectLimit	*selectlimit;
 	SetQuantifier	 setquantifier;
 	struct GroupClause  *groupclause;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -534,7 +542,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -610,6 +618,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -635,7 +710,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -645,7 +720,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -656,12 +731,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -672,9 +747,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -687,7 +763,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -695,17 +771,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -713,7 +789,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -738,7 +814,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -756,6 +832,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -791,11 +868,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -813,6 +894,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -12850,6 +12934,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -12868,6 +12953,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13161,7 +13247,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13236,6 +13322,14 @@ interval_second:
 				}
 		;
 
+/* Mapping of PG jsonb types to SQL/JSON JSON type */
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName(SQLJSON_TYPE_NAME());
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13692,6 +13786,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13774,6 +13908,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14026,6 +14179,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14039,6 +14201,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14326,6 +14489,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15024,6 +15189,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15490,6 +16179,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15530,6 +16220,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15566,10 +16257,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15586,6 +16279,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15617,7 +16311,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15660,6 +16356,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15689,6 +16386,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15718,6 +16416,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15769,6 +16468,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -15826,6 +16526,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -15893,6 +16603,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -15994,6 +16705,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16056,6 +16768,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16108,11 +16821,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16133,6 +16848,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16177,7 +16893,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16234,6 +16962,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16270,6 +16999,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16303,6 +17033,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16337,6 +17068,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16370,6 +17102,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 4133526f04..9db8967c60 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 2d1a477154..678840593b 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,8 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +78,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +320,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3094,3 +3157,1411 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format = JS_FORMAT_JSONB;
+		}
+		else if (have_json)
+		{
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+		else
+		{
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = SQLJSON_TYPE_OID();
+		JsonFormatType format =
+			SQLJSON_TYPE_IS_JSONB() ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 6e8fbc4780..f390b29637 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1958,6 +1958,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 875de7ba28..683e1ebcfa 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 0e8e065457..0f7646996a 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -23,6 +23,7 @@
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
 #include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/numeric.h"
 #include "utils/syscache.h"
@@ -294,6 +295,14 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "pg_catalog.json" : "json");
+			break;
+
+		case JSONBOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "json" : "jsonb");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index a1145e2721..1f88f8d828 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1018,11 +1018,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6673,3 +6668,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 30ca2cf6c8..3e5bb37369 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index 8d1e7fbf91..d11683c962 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -90,6 +69,8 @@ static JsonbParseState *clone_parse_state(JsonbParseState *state);
 static char *JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool indent);
 static void add_indent(StringInfo out, bool indent, int level);
 
+int			sql_json_type;		/* GUC for mapping jsonb to SQL/JSON JSON */
+
 /*
  * jsonb type input function
  */
@@ -98,7 +79,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +103,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +144,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +242,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +252,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +288,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +611,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1118,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1171,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1182,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1203,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1231,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1269,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
 }
 
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
+}
+
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1553,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1566,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1615,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1687,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1737,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1753,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1773,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1811,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1875,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1957,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2225,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 5711187795..a4117617d4 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -63,7 +63,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -688,7 +689,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -731,6 +734,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1935,7 +1941,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1945,15 +1951,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 6335845d08..7e1cb032f8 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2771,11 +2771,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3247,6 +3247,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5638,3 +5682,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index fa22546f22..43c9871506 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->val, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 078aaef539..3b596be9fa 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index ccd2835c22..b32f3b30c9 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -63,6 +63,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/hsearch.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
@@ -453,6 +454,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -486,6 +493,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6151,7 +6160,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -7992,6 +8002,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8085,6 +8097,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8108,6 +8121,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8163,6 +8177,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8269,6 +8288,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9444,6 +9578,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->val);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9541,6 +9779,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9686,17 +9925,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == SQLJSON_TYPE_OID()))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9726,13 +10049,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9768,7 +10092,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9782,6 +10116,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9791,6 +10128,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9810,10 +10157,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9837,16 +10186,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9883,6 +10246,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10123,6 +10495,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index 23236fa4c3..8975065e1e 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -95,6 +95,7 @@
 #include "utils/bytea.h"
 #include "utils/float.h"
 #include "utils/guc_tables.h"
+#include "utils/jsonb.h"
 #include "utils/memutils.h"
 #include "utils/pg_locale.h"
 #include "utils/pg_lsn.h"
@@ -556,6 +557,12 @@ static const struct config_enum_entry wal_compression_options[] = {
 	{NULL, 0, false}
 };
 
+const struct config_enum_entry sql_json_type_info[] = {
+	{"json", SQLJSON_TYPE_JSON, false},
+	{"jsonb", SQLJSON_TYPE_JSONB, false},
+	{NULL, 0, false}
+};
+
 /*
  * Options for enum values stored in other modules
  */
@@ -4982,6 +4989,18 @@ static struct config_enum ConfigureNamesEnum[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"sql_json", PGC_USERSET, COMPAT_OPTIONS_CLIENT,
+			gettext_noop("Sets what PostgreSQL type to use as an implementaion of SQL JSON type."),
+			gettext_noop("When turned on, jsonb type is mapped to SQL JSON type, "
+						 "json type is mapped to JSON TEXT type.")
+		},
+		&sql_json_type,
+		SQLJSON_TYPE_JSON,
+		sql_json_type_info,
+		NULL, NULL, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, 0, NULL, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 3fe9a53cb3..3292846f89 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -762,6 +762,7 @@
 # - Other Platforms and Clients -
 
 #transform_null_equals = off
+#sql_json = json # jsonb
 
 
 #------------------------------------------------------------------------------
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 9f2cd1f127..fd632d712e 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(castNode(String, temp)->val);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index fc6d3bfd94..aaf6e20e0b 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -561,14 +561,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d068d6532e..50a773009f 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8722,6 +8722,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8729,10 +8733,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8741,6 +8761,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9613,6 +9646,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9621,10 +9658,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9633,6 +9689,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 6a24341faa..00916724d9 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 3dc03c913e..09e3cde548 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 48a7ebfe45..3f55d4b7fb 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index b3ee4194d3..f6e71974b8 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -488,6 +498,20 @@ typedef enum NodeTag
 	T_PartitionCmd,
 	T_VacuumRelation,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 45e4f2a16e..1007128c57 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1550,6 +1550,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 7b125904b4..5e5f7fed5e 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1235,6 +1235,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format;		/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f836acf876..458f55fbec 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 93f979f320..c20a6a6d5f 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 7daf09f20e..f16cfdcb71 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4e07debf78..be5cc0e397 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,36 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
+
+/* values for the sql+json_type GUC. */
+typedef enum SqlJsonType
+{
+	SQLJSON_TYPE_JSON = 0,
+	SQLJSON_TYPE_JSONB = 1
+} SqlJsonType;
+
+#define SQLJSON_TYPE_IS_JSONB() (sql_json_type == SQLJSON_TYPE_JSONB)
+#define SQLJSON_TYPE_OID() (SQLJSON_TYPE_IS_JSONB() ? JSONBOID : JSONOID)
+#define SQLJSON_TYPE_NAME() (SQLJSON_TYPE_IS_JSONB() ? "jsonb" : "json")
+
+/* GUC */
+extern int sql_json_type;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +433,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +448,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 0ca48591d0..9e9128e8b2 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 87d302b702..fd2663c22f 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index 1e24801a6f..5a8c2f3eef 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a8571a3ffa..c47dee05cb 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb.out b/src/test/regress/expected/jsonb.out
index 1add673968..0ec940ad60 100644
--- a/src/test/regress/expected/jsonb.out
+++ b/src/test/regress/expected/jsonb.out
@@ -5509,3 +5509,133 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
  12345
 (1 row)
 
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+        Table "public.test_json_as_json"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | json  |           |          | 
+ jb     | jsonb |           |          | 
+
+set sql_json = jsonb;
+select json(' { "aa": 1, "b" : 2 }');
+       json        
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+       jsonb       
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+\d test_json_as_json
+             Table "public.test_json_as_json"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | pg_catalog.json |           |          | 
+ jb     | json            |           |          | 
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+             Table "public.test_json_as_jsonb"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | json            |           |          | 
+ jb     | json            |           |          | 
+ jt     | pg_catalog.json |           |          | 
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(pg_catalog.json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
+set sql_json = json;
+\d test_json_as_jsonb
+        Table "public.test_json_as_jsonb"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | jsonb |           |          | 
+ jb     | jsonb |           |          | 
+ jt     | json  |           |          | 
+
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..f2f5e271b8
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 562b586d8e..e7d6358a25 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..51bd216120
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1352 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Result
+   Output: JSON('123'::pg_catalog.json RETURNING pg_catalog.json)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+    pg_typeof    
+-----------------
+ pg_catalog.json
+(1 row)
+
+SET sql_json = json;
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING pg_catalog.json)
+(2 rows)
+
+SET sql_json = json;
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 7be89178f0..810450164d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -108,7 +108,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb.sql b/src/test/regress/sql/jsonb.sql
index 5016f29c15..4af2a0cb11 100644
--- a/src/test/regress/sql/jsonb.sql
+++ b/src/test/regress/sql/jsonb.sql
@@ -1482,3 +1482,41 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
+
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+
+set sql_json = jsonb;
+
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+\d test_json_as_json
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+
+set sql_json = json;
+\d test_json_as_jsonb
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 5a9c479692..7a849ae363 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..4ff6076763
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,467 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+
+SET sql_json = json;
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+
+SET sql_json = json;
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.4

0002-JSON_TABLE-v51.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v51.patchDownload
From 0a488895c9b51da9b8b8dec7bc9195a920172f95 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Mon, 13 Sep 2021 17:56:57 -0400
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  19 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  10 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 467 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 227 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  37 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2885 insertions(+), 32 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index a75b92bdb9..e86c8992c3 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18524,6 +18524,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19194,6 +19199,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 10644dfac4..9ba9eb6d27 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3784,7 +3784,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index efcfde8c95..76f9ee6564 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0d4d30853e..3be81abc91 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4608,6 +4608,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4700,8 +4701,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4837,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	/* Want to execute expressions inside function's memory context */
 	MemoryContextSwitchTo(oldcontext);
 
+
 	PG_TRY();
 	{
 		res = func(op, econtext, res, resnull, p, error);
@@ -4849,6 +4857,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4860,8 +4869,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4987,6 +4998,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 27dfa1b956..e4a5f1b6fe 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index ba2eb0f894..5e35e57697 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1390,6 +1390,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1400,7 +1401,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2662,6 +2665,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5739,6 +5812,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index ffb186825f..adcb608756 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3595,6 +3618,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 97bd0bac6b..eb739f2ee0 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2434,6 +2434,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3445,6 +3447,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4401,6 +4404,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index c3aa51c639..80bb16e504 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1088,6 +1088,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1098,7 +1099,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1862,6 +1865,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4662,6 +4685,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index cbffe4695e..cc173a38ec 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -535,6 +535,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -545,7 +546,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1496,6 +1499,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3150,6 +3177,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index b70949b122..01804dab46 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -645,15 +645,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -667,6 +677,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -674,6 +685,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -748,7 +761,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -758,8 +771,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -767,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -869,7 +882,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -894,6 +907,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12290,6 +12307,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12834,6 +12864,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15361,6 +15393,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15475,6 +15511,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16339,6 +16522,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16372,6 +16556,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16535,6 +16720,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -16902,6 +17088,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -16939,6 +17126,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16982,6 +17170,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 078029ba1f..cea66ec5f8 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,7 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1100,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 678840593b..579c68a929 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4092,7 +4092,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4130,14 +4130,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4438,6 +4437,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..94c96606c1
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,467 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  pasring of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.val = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.val;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index c5c3f26ecf..decb2c2234 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index f390b29637..26143f973d 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1993,6 +1993,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 3b596be9fa..ebfa226bf3 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->val);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b32f3b30c9..a52337b586 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -495,6 +495,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8378,7 +8380,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9641,6 +9644,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10889,16 +10895,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10989,6 +10993,219 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->val));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index fd632d712e..c0f8bcc11b 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 00916724d9..0abe9d1ee4 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index f6e71974b8..f2057ac291 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -507,6 +509,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1007128c57..55dbdd8107 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1563,6 +1563,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1622,6 +1635,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 5e5f7fed5e..57420a572f 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1243,7 +1252,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1457,6 +1467,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 458f55fbec..15f586d455 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 0eab3c03e8..9216f81acb 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index fd2663c22f..3c37ea087a 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index f2f5e271b8..d89c3bef44 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..6614dd6e45 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 423780652f..063d639f65 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1231,6 +1231,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2618,6 +2626,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.4

0003-JSON_TABLE-PLAN-DEFAULT-clause-v51.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v51.patchDownload
From 074417afc8be747a235729d7f3732c101f520baf Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Mon, 13 Sep 2021 18:03:14 -0400
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 462 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index e86c8992c3..746f24501a 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19207,6 +19207,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19268,7 +19272,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19281,22 +19286,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parrent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19468,6 +19457,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19490,8 +19483,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 5e35e57697..ffa8f7e39b 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2677,6 +2677,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2715,6 +2716,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2731,6 +2734,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index adcb608756..5351be8bb4 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -152,6 +152,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -163,6 +165,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 80bb16e504..2a18d6ad66 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1872,6 +1872,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1883,6 +1885,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index cc173a38ec..b9f12205b3 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1506,6 +1506,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1519,6 +1521,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 01804dab46..f9ab89bf99 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -667,6 +667,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -780,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15515,13 +15520,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15658,6 +15665,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16557,6 +16592,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17172,6 +17208,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 94c96606c1..41fe7659de 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -174,12 +174,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -187,7 +188,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -195,8 +196,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -208,7 +210,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -386,6 +388,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index ebfa226bf3..4512c529e7 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a52337b586..780f6520c6 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11182,6 +11182,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 55dbdd8107..0de78dd6ad 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1655,6 +1655,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1664,6 +1676,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 57420a572f..1aa3e01048 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1476,6 +1476,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1490,6 +1492,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 15f586d455..6065bbae88 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index d89c3bef44..0cd8f73c66 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 6614dd6e45..cd97ff7f46 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 063d639f65..27cf806043 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1237,6 +1237,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.4

0004-JSON_TABLE-PLAN-clause-v51.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v51.patchDownload
From d4f4cf355094ec4a9c05f192e15d0f1d3294c1f6 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Mon, 13 Sep 2021 18:18:24 -0400
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 322 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1389 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 746f24501a..a660cdf956 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19205,9 +19205,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19231,6 +19232,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19273,7 +19284,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19458,7 +19469,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19485,18 +19496,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19575,6 +19599,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19606,9 +19647,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index ffa8f7e39b..f3d84485fe 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2675,9 +2675,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2695,6 +2695,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2706,6 +2707,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2715,9 +2734,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5822,6 +5841,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 5351be8bb4..123d5062e7 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -151,9 +151,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index ca374dcb29..46d7f61e25 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -864,6 +864,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 2a18d6ad66..8c0b78d73f 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1871,9 +1871,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index b9f12205b3..d73689ee97 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1505,9 +1505,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f9ab89bf99..1ed59f63c8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -652,6 +652,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -667,8 +679,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15527,7 +15537,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15649,12 +15659,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15666,12 +15679,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 41fe7659de..eae5e699db 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -38,12 +38,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -156,19 +159,154 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -186,34 +324,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -377,19 +559,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -407,7 +650,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -415,9 +660,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -453,7 +720,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.val;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 780f6520c6..e19749d12a 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11019,10 +11019,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11151,6 +11195,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11182,14 +11228,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 3f55d4b7fb..405547bad6 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0de78dd6ad..d5f7dbcaa9 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1646,6 +1646,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1655,6 +1656,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1667,6 +1679,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1676,7 +1705,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 1aa3e01048..7884578cec 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1475,9 +1475,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0cd8f73c66..81f94e3c91 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE path names and column names shall be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index cd97ff7f46..be2d65b3ff 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 27cf806043..38cb738c1a 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1237,7 +1237,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.4

#59Erik Rijkers
er@xs4all.nl
In reply to: Andrew Dunstan (#58)
Re: SQL/JSON: JSON_TABLE - pg_stat_statements crash

On 9/14/21 2:53 PM, Andrew Dunstan wrote:

On 9/13/21 5:41 AM, Erik Rijkers wrote:

On 9/2/21 8:52 PM, Andrew Dunstan wrote:

[0001-SQL-JSON-functions-v51.patch]
[0002-JSON_TABLE-v51.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v51.patch]
[0004-JSON_TABLE-PLAN-clause-v51.patch]

Thanks, builds fine now.

But I found that the server crashes on certain forms of SQL when
postgresql.conf has a 'shared_preload_libraries' that contains module
'pg_stat_statements' (my value was:
'pg_stat_statements,auth_delay,auto_explain,passwordcheck'). Only
pg_stat_statements seems to cause the problem.

The offending SQL (I took it from the jsonb_sqljson.sql test file):

testdb=# SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x &&
@ < $y)' PASSING 0 AS x, 2 AS y);
server closed the connection unexpectedly
This probably means the server terminated abnormally
before or while processing the request.
The connection to the server was lost. Attempting reset: Failed.
Time: 2.551 ms
!?>

(Of course, that SQL running during regression testing has no problems
as there is then no pg_stat_statements.)

The statement sometimes succeeds but never very often.

The same crash was there before but I only now saw the connection with
the 'shared_preload_libraries/pg_stat_statements'.

I seem to remember some things changed in pg_stat_statements but I
didn't follow and don't know who to CC for it.

Thanks,

Erik Rijkers

#60Pavel Stehule
pavel.stehule@gmail.com
In reply to: Erik Rijkers (#59)
Re: SQL/JSON: JSON_TABLE - pg_stat_statements crash

út 14. 9. 2021 v 20:04 odesílatel Erik Rijkers <er@xs4all.nl> napsal:

On 9/14/21 2:53 PM, Andrew Dunstan wrote:

On 9/13/21 5:41 AM, Erik Rijkers wrote:

On 9/2/21 8:52 PM, Andrew Dunstan wrote:

[0001-SQL-JSON-functions-v51.patch]
[0002-JSON_TABLE-v51.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v51.patch]
[0004-JSON_TABLE-PLAN-clause-v51.patch]

Thanks, builds fine now.

But I found that the server crashes on certain forms of SQL when
postgresql.conf has a 'shared_preload_libraries' that contains module
'pg_stat_statements' (my value was:
'pg_stat_statements,auth_delay,auto_explain,passwordcheck'). Only
pg_stat_statements seems to cause the problem.

The offending SQL (I took it from the jsonb_sqljson.sql test file):

testdb=# SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x &&
@ < $y)' PASSING 0 AS x, 2 AS y);
server closed the connection unexpectedly
This probably means the server terminated abnormally
before or while processing the request.
The connection to the server was lost. Attempting reset: Failed.
Time: 2.551 ms
!?>

(Of course, that SQL running during regression testing has no problems
as there is then no pg_stat_statements.)

The statement sometimes succeeds but never very often.

The same crash was there before but I only now saw the connection with
the 'shared_preload_libraries/pg_stat_statements'.

I seem to remember some things changed in pg_stat_statements but I
didn't follow and don't know who to CC for it.

These issues are easily debugged - you can run gdb in the outer terminal,
and attach it to the psql session. Then you can run the query.

Probably it will be a problem in pg_stat_statements callbacks - maybe query
processing there doesn't know some new nodes that this patch introduces.

Regards

Pavel

Show quoted text

Thanks,

Erik Rijkers

#61Andrew Dunstan
andrew@dunslane.net
In reply to: Erik Rijkers (#59)
Re: SQL/JSON: JSON_TABLE - pg_stat_statements crash

On 9/14/21 2:04 PM, Erik Rijkers wrote:

On 9/14/21 2:53 PM, Andrew Dunstan wrote:

On 9/13/21 5:41 AM, Erik Rijkers wrote:

On 9/2/21 8:52 PM, Andrew Dunstan wrote:

[0001-SQL-JSON-functions-v51.patch]
[0002-JSON_TABLE-v51.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v51.patch]
[0004-JSON_TABLE-PLAN-clause-v51.patch]

Thanks, builds fine now.

But I found that the server crashes on certain forms of SQL when
postgresql.conf has a 'shared_preload_libraries' that contains module
'pg_stat_statements' (my value was:
'pg_stat_statements,auth_delay,auto_explain,passwordcheck').  Only
pg_stat_statements seems to cause the problem.

The offending SQL (I took it from the jsonb_sqljson.sql test file):

testdb=# SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x
&& @ < $y)' PASSING 0 AS x, 2 AS y);
server closed the connection unexpectedly
        This probably means the server terminated abnormally
        before or while processing the request.
The connection to the server was lost. Attempting reset: Failed.
Time: 2.551 ms
!?>

(Of course, that SQL running during regression testing has no problems
as there is then no pg_stat_statements.)

The statement sometimes succeeds but never very often.

The same crash was there before but I only now saw the connection with
the 'shared_preload_libraries/pg_stat_statements'.

I seem to remember some things changed in pg_stat_statements but I
didn't follow and don't know who to CC for it.

Yeah, I had to make a change in that area, looks like I got it wrong.
I'll follow up. Thanks for the report.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#62Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#61)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 9/14/21 3:18 PM, Andrew Dunstan wrote:

On 9/14/21 2:04 PM, Erik Rijkers wrote:

On 9/14/21 2:53 PM, Andrew Dunstan wrote:

On 9/13/21 5:41 AM, Erik Rijkers wrote:

On 9/2/21 8:52 PM, Andrew Dunstan wrote:

[0001-SQL-JSON-functions-v51.patch]
[0002-JSON_TABLE-v51.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v51.patch]
[0004-JSON_TABLE-PLAN-clause-v51.patch]

Thanks, builds fine now.

But I found that the server crashes on certain forms of SQL when
postgresql.conf has a 'shared_preload_libraries' that contains module
'pg_stat_statements' (my value was:
'pg_stat_statements,auth_delay,auto_explain,passwordcheck').  Only
pg_stat_statements seems to cause the problem.

The offending SQL (I took it from the jsonb_sqljson.sql test file):

testdb=# SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x
&& @ < $y)' PASSING 0 AS x, 2 AS y);
server closed the connection unexpectedly
        This probably means the server terminated abnormally
        before or while processing the request.
The connection to the server was lost. Attempting reset: Failed.
Time: 2.551 ms
!?>

(Of course, that SQL running during regression testing has no problems
as there is then no pg_stat_statements.)

The statement sometimes succeeds but never very often.

The same crash was there before but I only now saw the connection with
the 'shared_preload_libraries/pg_stat_statements'.

I seem to remember some things changed in pg_stat_statements but I
didn't follow and don't know who to CC for it.

Yeah, I had to make a change in that area, looks like I got it wrong.
I'll follow up. Thanks for the report.

Rebased and fixed. It's actually an old bug, I reproduced it with a
previous patch set.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-v52.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-v52.patchDownload
From 1775d3b30581c4c569cc1f85381abac32c26f8c1 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 16 Sep 2021 10:28:55 -0400
Subject: [PATCH 1/4] SQL/JSON functions

Common SQL/JSON clauses
SQL/JSON constructors
IS JSON predicate
SQL/JSON query functions
SQL/JSON functions for json type
GUC sql_json
---
 doc/src/sgml/config.sgml                      |   19 +
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  767 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1471 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    9 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  352 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  437 +++-
 src/backend/utils/misc/guc.c                  |   19 +
 src/backend/utils/misc/postgresql.conf.sample |    1 +
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   47 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb.out           |  130 ++
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1352 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb.sql                |   38 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  467 ++++
 59 files changed, 13151 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index ef0e2a7746..1b9a552ec8 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -9500,6 +9500,25 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir'
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-sql-json" xreflabel="sql_json">
+      <term><varname>sql_json</varname> (<type>enum</type>)
+      <indexterm><primary>json</primary></indexterm>
+      <indexterm><primary>jsonb</primary></indexterm>
+      <indexterm>
+       <primary><varname>sql_json</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+         Valid values are <literal>json</literal> and <literal>jsonb</literal>.
+         Specifies what <productname>PostgreSQL</productname> type is used
+         as an implementation of SQL type <type>JSON</type>.
+         When <varname>sql_json</varname> is set to <literal>jsonb</literal>,
+         <productname>PostgreSQL</productname> type <type>json</type> can be
+         accessed using explicit qualification <type>pg_catalog.json</type>.
+       </para>
+      </listitem>
+     </varlistentry>
      </variablelist>
     </sect2>
    </sect1>
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 78812b2dbe..a75b92bdb9 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17456,6 +17456,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19596,6 +21514,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 81b9d87bad..efcfde8c95 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->val);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index eb49817cee..0d4d30853e 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4386,3 +4503,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index 6d1181225e..15c9ee44c0 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index 2deb65c5b5..b507d98ca1 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 228387eaee..ba2eb0f894 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2295,6 +2295,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5306,6 +5673,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 800f588b5c..ffb186825f 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3326,6 +3562,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3897,6 +4166,30 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 7d1a01d1ed..928570b22e 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -815,3 +816,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index e276264882..97bd0bac6b 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2328,6 +2436,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2658,6 +2838,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3267,6 +3448,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -3974,6 +4250,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 2e5ed77e18..8012904870 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1748,6 +1748,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4521,6 +4635,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index abf08b7a2f..2eee045db0 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1391,6 +1391,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2973,6 +3132,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 1e4d404f02..5033e8c87a 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4540,7 +4540,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index 3412d31117..c1951c1caf 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -381,6 +385,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -852,6 +895,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3511,6 +3566,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index e3068a374e..b70949b122 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -62,6 +62,7 @@
 #include "storage/lmgr.h"
 #include "utils/date.h"
 #include "utils/datetime.h"
+#include "utils/jsonb.h"
 #include "utils/numeric.h"
 #include "utils/xml.h"
 
@@ -259,6 +260,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct SelectLimit	*selectlimit;
 	SetQuantifier	 setquantifier;
 	struct GroupClause  *groupclause;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -534,7 +542,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -610,6 +618,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -635,7 +710,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -645,7 +720,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -656,12 +731,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -672,9 +747,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -687,7 +763,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -695,17 +771,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -713,7 +789,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -738,7 +814,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -756,6 +832,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -791,11 +868,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -813,6 +894,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -12850,6 +12934,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -12868,6 +12953,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13161,7 +13247,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13236,6 +13322,14 @@ interval_second:
 				}
 		;
 
+/* Mapping of PG jsonb types to SQL/JSON JSON type */
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName(SQLJSON_TYPE_NAME());
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13692,6 +13786,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13774,6 +13908,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14026,6 +14179,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14039,6 +14201,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14326,6 +14489,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15024,6 +15189,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15490,6 +16179,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15530,6 +16220,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15566,10 +16257,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15586,6 +16279,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15617,7 +16311,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15660,6 +16356,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15689,6 +16386,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15718,6 +16416,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15769,6 +16468,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -15826,6 +16526,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -15893,6 +16603,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -15994,6 +16705,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16056,6 +16768,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16108,11 +16821,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16133,6 +16848,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16177,7 +16893,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16234,6 +16962,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16270,6 +16999,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16303,6 +17033,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16337,6 +17068,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16370,6 +17102,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 4133526f04..9db8967c60 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 2d1a477154..678840593b 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,8 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +78,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +320,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3094,3 +3157,1411 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format = JS_FORMAT_JSONB;
+		}
+		else if (have_json)
+		{
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+		else
+		{
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = SQLJSON_TYPE_OID();
+		JsonFormatType format =
+			SQLJSON_TYPE_IS_JSONB() ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 6e8fbc4780..f390b29637 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1958,6 +1958,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 875de7ba28..683e1ebcfa 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 0e8e065457..0f7646996a 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -23,6 +23,7 @@
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
 #include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/numeric.h"
 #include "utils/syscache.h"
@@ -294,6 +295,14 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "pg_catalog.json" : "json");
+			break;
+
+		case JSONBOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "json" : "jsonb");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index a1145e2721..1f88f8d828 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1018,11 +1018,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6673,3 +6668,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 30ca2cf6c8..3e5bb37369 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index 8d1e7fbf91..d11683c962 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -90,6 +69,8 @@ static JsonbParseState *clone_parse_state(JsonbParseState *state);
 static char *JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool indent);
 static void add_indent(StringInfo out, bool indent, int level);
 
+int			sql_json_type;		/* GUC for mapping jsonb to SQL/JSON JSON */
+
 /*
  * jsonb type input function
  */
@@ -98,7 +79,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +103,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +144,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +242,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +252,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +288,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +611,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1118,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1171,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1182,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1203,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1231,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1269,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
 }
 
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
+}
+
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1553,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1566,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1615,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1687,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1737,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1753,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1773,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1811,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1875,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1957,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2225,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 5711187795..a4117617d4 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -63,7 +63,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -688,7 +689,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -731,6 +734,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1935,7 +1941,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1945,15 +1951,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 6335845d08..7e1cb032f8 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2771,11 +2771,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3247,6 +3247,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5638,3 +5682,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index fa22546f22..43c9871506 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->val, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 078aaef539..3b596be9fa 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b932a83827..439f48feb4 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -63,6 +63,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/hsearch.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
@@ -453,6 +454,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -486,6 +493,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6151,7 +6160,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -7992,6 +8002,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8085,6 +8097,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8108,6 +8121,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8163,6 +8177,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8269,6 +8288,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9444,6 +9578,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->val);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9541,6 +9779,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9686,17 +9925,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == SQLJSON_TYPE_OID()))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9726,13 +10049,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9768,7 +10092,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9782,6 +10116,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9791,6 +10128,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9810,10 +10157,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9837,16 +10186,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9883,6 +10246,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10123,6 +10495,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index a6e4fcc24e..f1a0327148 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -95,6 +95,7 @@
 #include "utils/bytea.h"
 #include "utils/float.h"
 #include "utils/guc_tables.h"
+#include "utils/jsonb.h"
 #include "utils/memutils.h"
 #include "utils/pg_locale.h"
 #include "utils/pg_lsn.h"
@@ -556,6 +557,12 @@ static const struct config_enum_entry wal_compression_options[] = {
 	{NULL, 0, false}
 };
 
+const struct config_enum_entry sql_json_type_info[] = {
+	{"json", SQLJSON_TYPE_JSON, false},
+	{"jsonb", SQLJSON_TYPE_JSONB, false},
+	{NULL, 0, false}
+};
+
 /*
  * Options for enum values stored in other modules
  */
@@ -4982,6 +4989,18 @@ static struct config_enum ConfigureNamesEnum[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"sql_json", PGC_USERSET, COMPAT_OPTIONS_CLIENT,
+			gettext_noop("Sets what PostgreSQL type to use as an implementaion of SQL JSON type."),
+			gettext_noop("When turned on, jsonb type is mapped to SQL JSON type, "
+						 "json type is mapped to JSON TEXT type.")
+		},
+		&sql_json_type,
+		SQLJSON_TYPE_JSON,
+		sql_json_type_info,
+		NULL, NULL, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, 0, NULL, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 3fe9a53cb3..3292846f89 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -762,6 +762,7 @@
 # - Other Platforms and Clients -
 
 #transform_null_equals = off
+#sql_json = json # jsonb
 
 
 #------------------------------------------------------------------------------
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 9f2cd1f127..9b1252f06d 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(lfirst_node(String, temp)->val);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index fc6d3bfd94..aaf6e20e0b 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -561,14 +561,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d068d6532e..50a773009f 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8722,6 +8722,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8729,10 +8733,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8741,6 +8761,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9613,6 +9646,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9621,10 +9658,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9633,6 +9689,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 6a24341faa..00916724d9 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index cd57a704ad..26a4bd28ee 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index eea87f847d..c1cfbfc6b3 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index e0057daa06..5edf7aecee 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -488,6 +498,20 @@ typedef enum NodeTag
 	T_PartitionCmd,
 	T_VacuumRelation,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 3138877553..f8390ee9c0 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1550,6 +1550,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 433437643e..0af3d0bb2f 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1235,6 +1235,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format;		/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f836acf876..458f55fbec 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 93f979f320..c20a6a6d5f 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 7daf09f20e..f16cfdcb71 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4e07debf78..be5cc0e397 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,36 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
+
+/* values for the sql+json_type GUC. */
+typedef enum SqlJsonType
+{
+	SQLJSON_TYPE_JSON = 0,
+	SQLJSON_TYPE_JSONB = 1
+} SqlJsonType;
+
+#define SQLJSON_TYPE_IS_JSONB() (sql_json_type == SQLJSON_TYPE_JSONB)
+#define SQLJSON_TYPE_OID() (SQLJSON_TYPE_IS_JSONB() ? JSONBOID : JSONOID)
+#define SQLJSON_TYPE_NAME() (SQLJSON_TYPE_IS_JSONB() ? "jsonb" : "json")
+
+/* GUC */
+extern int sql_json_type;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +433,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +448,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 0ca48591d0..9e9128e8b2 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 87d302b702..fd2663c22f 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index 1e24801a6f..5a8c2f3eef 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a8571a3ffa..c47dee05cb 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb.out b/src/test/regress/expected/jsonb.out
index a9cd145aec..905b50e850 100644
--- a/src/test/regress/expected/jsonb.out
+++ b/src/test/regress/expected/jsonb.out
@@ -5509,3 +5509,133 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
  12345
 (1 row)
 
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+        Table "public.test_json_as_json"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | json  |           |          | 
+ jb     | jsonb |           |          | 
+
+set sql_json = jsonb;
+select json(' { "aa": 1, "b" : 2 }');
+       json        
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+       jsonb       
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+\d test_json_as_json
+             Table "public.test_json_as_json"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | pg_catalog.json |           |          | 
+ jb     | json            |           |          | 
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+             Table "public.test_json_as_jsonb"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | json            |           |          | 
+ jb     | json            |           |          | 
+ jt     | pg_catalog.json |           |          | 
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(pg_catalog.json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
+set sql_json = json;
+\d test_json_as_jsonb
+        Table "public.test_json_as_jsonb"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | jsonb |           |          | 
+ jb     | jsonb |           |          | 
+ jt     | json  |           |          | 
+
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..f2f5e271b8
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 562b586d8e..e7d6358a25 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..51bd216120
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1352 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Result
+   Output: JSON('123'::pg_catalog.json RETURNING pg_catalog.json)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+    pg_typeof    
+-----------------
+ pg_catalog.json
+(1 row)
+
+SET sql_json = json;
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING pg_catalog.json)
+(2 rows)
+
+SET sql_json = json;
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 7be89178f0..810450164d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -108,7 +108,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb.sql b/src/test/regress/sql/jsonb.sql
index 5016f29c15..4af2a0cb11 100644
--- a/src/test/regress/sql/jsonb.sql
+++ b/src/test/regress/sql/jsonb.sql
@@ -1482,3 +1482,41 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
+
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+
+set sql_json = jsonb;
+
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+\d test_json_as_json
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+
+set sql_json = json;
+\d test_json_as_jsonb
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 5a9c479692..7a849ae363 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..4ff6076763
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,467 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+
+SET sql_json = json;
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+
+SET sql_json = json;
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.4

0002-JSON_TABLE-v52.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v52.patchDownload
From 641878c1496916c2b6b24a095ff3a88a7f22290b Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 16 Sep 2021 10:31:39 -0400
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  19 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  10 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 467 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 227 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  37 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2885 insertions(+), 32 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index a75b92bdb9..e86c8992c3 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18524,6 +18524,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19194,6 +19199,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 10644dfac4..9ba9eb6d27 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3784,7 +3784,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index efcfde8c95..76f9ee6564 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0d4d30853e..3be81abc91 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4608,6 +4608,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4700,8 +4701,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4837,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	/* Want to execute expressions inside function's memory context */
 	MemoryContextSwitchTo(oldcontext);
 
+
 	PG_TRY();
 	{
 		res = func(op, econtext, res, resnull, p, error);
@@ -4849,6 +4857,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4860,8 +4869,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4987,6 +4998,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 27dfa1b956..e4a5f1b6fe 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index ba2eb0f894..5e35e57697 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1390,6 +1390,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1400,7 +1401,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2662,6 +2665,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5739,6 +5812,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index ffb186825f..adcb608756 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3595,6 +3618,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 97bd0bac6b..eb739f2ee0 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2434,6 +2434,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3445,6 +3447,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4401,6 +4404,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 8012904870..0ec2b6b831 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1088,6 +1088,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1098,7 +1099,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1862,6 +1865,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4662,6 +4685,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 2eee045db0..833f6627cf 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -535,6 +535,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -545,7 +546,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1496,6 +1499,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3150,6 +3177,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index b70949b122..01804dab46 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -645,15 +645,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -667,6 +677,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -674,6 +685,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -748,7 +761,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -758,8 +771,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -767,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -869,7 +882,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -894,6 +907,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12290,6 +12307,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -12834,6 +12864,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15361,6 +15393,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15475,6 +15511,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16339,6 +16522,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16372,6 +16556,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16535,6 +16720,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -16902,6 +17088,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -16939,6 +17126,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16982,6 +17170,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 078029ba1f..cea66ec5f8 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,7 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1100,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 678840593b..579c68a929 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4092,7 +4092,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4130,14 +4130,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4438,6 +4437,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..94c96606c1
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,467 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  pasring of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.val = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.val;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index c5c3f26ecf..decb2c2234 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index f390b29637..26143f973d 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1993,6 +1993,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 3b596be9fa..ebfa226bf3 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->val);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 439f48feb4..58d0fe4da0 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -495,6 +495,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8378,7 +8380,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9641,6 +9644,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10889,16 +10895,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -10989,6 +10993,219 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->val));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 9b1252f06d..fa1374f2fd 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 00916724d9..0abe9d1ee4 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 5edf7aecee..40a8d54594 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -507,6 +509,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index f8390ee9c0..72f0e6aa79 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1563,6 +1563,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1622,6 +1635,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 0af3d0bb2f..da8cd5fbd5 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1243,7 +1252,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1457,6 +1467,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 458f55fbec..15f586d455 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 0eab3c03e8..9216f81acb 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index fd2663c22f..3c37ea087a 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index f2f5e271b8..d89c3bef44 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..6614dd6e45 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 402a6617a9..2e8513dc68 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1231,6 +1231,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2619,6 +2627,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.4

0003-JSON_TABLE-PLAN-DEFAULT-clause-v52.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v52.patchDownload
From 3d4f7fb9e2ab764189ca698a9eb384c140dde162 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 16 Sep 2021 10:33:01 -0400
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 462 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index e86c8992c3..746f24501a 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19207,6 +19207,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19268,7 +19272,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19281,22 +19286,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parrent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19468,6 +19457,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19490,8 +19483,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 5e35e57697..ffa8f7e39b 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2677,6 +2677,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2715,6 +2716,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2731,6 +2734,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index adcb608756..5351be8bb4 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -152,6 +152,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -163,6 +165,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 0ec2b6b831..5485d1bf03 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1872,6 +1872,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1883,6 +1885,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 833f6627cf..723fb3ee1a 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1506,6 +1506,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1519,6 +1521,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 01804dab46..f9ab89bf99 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -667,6 +667,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -780,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15515,13 +15520,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15658,6 +15665,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16557,6 +16592,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17172,6 +17208,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 94c96606c1..41fe7659de 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -174,12 +174,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -187,7 +188,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -195,8 +196,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -208,7 +210,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -386,6 +388,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index ebfa226bf3..4512c529e7 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 58d0fe4da0..d21a11eabb 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11182,6 +11182,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 72f0e6aa79..86026f0e96 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1655,6 +1655,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1664,6 +1676,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index da8cd5fbd5..be5e0482de 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1476,6 +1476,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1490,6 +1492,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 15f586d455..6065bbae88 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index d89c3bef44..0cd8f73c66 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 6614dd6e45..cd97ff7f46 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 2e8513dc68..2e0fbcdabd 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1237,6 +1237,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.4

0004-JSON_TABLE-PLAN-clause-v52.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v52.patchDownload
From cce72e3881c92fba0b4475d80b7fb525b6f8d126 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 16 Sep 2021 10:34:19 -0400
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 322 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1389 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 746f24501a..a660cdf956 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19205,9 +19205,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19231,6 +19232,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19273,7 +19284,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19458,7 +19469,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19485,18 +19496,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19575,6 +19599,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19606,9 +19647,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index ffa8f7e39b..f3d84485fe 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2675,9 +2675,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2695,6 +2695,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2706,6 +2707,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2715,9 +2734,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5822,6 +5841,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 5351be8bb4..123d5062e7 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -151,9 +151,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 928570b22e..971fe4a548 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -864,6 +864,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 5485d1bf03..a9381ac244 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1871,9 +1871,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 723fb3ee1a..0aaba34120 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1505,9 +1505,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f9ab89bf99..1ed59f63c8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -652,6 +652,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -667,8 +679,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15527,7 +15537,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15649,12 +15659,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15666,12 +15679,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 41fe7659de..eae5e699db 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -38,12 +38,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -156,19 +159,154 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -186,34 +324,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -377,19 +559,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -407,7 +650,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -415,9 +660,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -453,7 +720,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.val;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d21a11eabb..8bbf6a488c 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11019,10 +11019,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11151,6 +11195,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11182,14 +11228,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index c1cfbfc6b3..018817021a 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 86026f0e96..6cdcbabd1d 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1646,6 +1646,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1655,6 +1656,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1667,6 +1679,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1676,7 +1705,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index be5e0482de..efc6afe777 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1475,9 +1475,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0cd8f73c66..81f94e3c91 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( 
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE path names and column names shall be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' 
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index cd97ff7f46..be2d65b3ff 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 2e0fbcdabd..e9c33d5715 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1237,7 +1237,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.4

#63Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#62)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 9/16/21 10:55, Andrew Dunstan wrote:

On 9/14/21 3:18 PM, Andrew Dunstan wrote:

On 9/14/21 2:04 PM, Erik Rijkers wrote:

On 9/14/21 2:53 PM, Andrew Dunstan wrote:

On 9/13/21 5:41 AM, Erik Rijkers wrote:

On 9/2/21 8:52 PM, Andrew Dunstan wrote:

[0001-SQL-JSON-functions-v51.patch]
[0002-JSON_TABLE-v51.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v51.patch]
[0004-JSON_TABLE-PLAN-clause-v51.patch]

Thanks, builds fine now.

But I found that the server crashes on certain forms of SQL when
postgresql.conf has a 'shared_preload_libraries' that contains module
'pg_stat_statements' (my value was:
'pg_stat_statements,auth_delay,auto_explain,passwordcheck').  Only
pg_stat_statements seems to cause the problem.

The offending SQL (I took it from the jsonb_sqljson.sql test file):

testdb=# SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x
&& @ < $y)' PASSING 0 AS x, 2 AS y);
server closed the connection unexpectedly
        This probably means the server terminated abnormally
        before or while processing the request.
The connection to the server was lost. Attempting reset: Failed.
Time: 2.551 ms
!?>

(Of course, that SQL running during regression testing has no problems
as there is then no pg_stat_statements.)

The statement sometimes succeeds but never very often.

The same crash was there before but I only now saw the connection with
the 'shared_preload_libraries/pg_stat_statements'.

I seem to remember some things changed in pg_stat_statements but I
didn't follow and don't know who to CC for it.

Yeah, I had to make a change in that area, looks like I got it wrong.
I'll follow up. Thanks for the report.

Rebased and fixed. It's actually an old bug, I reproduced it with a
previous patch set.

rebased again.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-v53.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-v53.patchDownload
From 161df4f71bd173804ee9a2f92ae1639cb88560b5 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 16 Sep 2021 10:28:55 -0400
Subject: [PATCH 1/4] SQL/JSON functions

Common SQL/JSON clauses
SQL/JSON constructors
IS JSON predicate
SQL/JSON query functions
SQL/JSON functions for json type
GUC sql_json
---
 doc/src/sgml/config.sgml                      |   19 +
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  767 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1471 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    9 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  352 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  437 +++-
 src/backend/utils/misc/guc.c                  |   19 +
 src/backend/utils/misc/postgresql.conf.sample |    1 +
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   47 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb.out           |  130 ++
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1352 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb.sql                |   38 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  467 ++++
 59 files changed, 13151 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index afbb6c35e3..de8955ea28 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -9534,6 +9534,25 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir'
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-sql-json" xreflabel="sql_json">
+      <term><varname>sql_json</varname> (<type>enum</type>)
+      <indexterm><primary>json</primary></indexterm>
+      <indexterm><primary>jsonb</primary></indexterm>
+      <indexterm>
+       <primary><varname>sql_json</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+         Valid values are <literal>json</literal> and <literal>jsonb</literal>.
+         Specifies what <productname>PostgreSQL</productname> type is used
+         as an implementation of SQL type <type>JSON</type>.
+         When <varname>sql_json</varname> is set to <literal>jsonb</literal>,
+         <productname>PostgreSQL</productname> type <type>json</type> can be
+         accessed using explicit qualification <type>pg_catalog.json</type>.
+       </para>
+      </listitem>
+     </varlistentry>
      </variablelist>
     </sect2>
    </sect1>
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index e58efce586..2c84905df1 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17563,6 +17563,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19716,6 +21634,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 7d343f0678..094c84008f 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->val);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index eb49817cee..0d4d30853e 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4386,3 +4503,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index 6d1181225e..15c9ee44c0 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index 2deb65c5b5..b507d98ca1 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index df0b747883..52422708a1 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2297,6 +2297,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5323,6 +5690,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index cb7ddd463c..1ce2ac1076 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3339,6 +3575,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3913,6 +4182,30 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 7d1a01d1ed..928570b22e 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -815,3 +816,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index e276264882..97bd0bac6b 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2328,6 +2436,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2658,6 +2838,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3267,6 +3448,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -3974,6 +4250,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 91a89b6d51..a45581a8ca 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1750,6 +1750,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4526,6 +4640,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index d79af6e56e..6d6b396e42 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1389,6 +1389,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2973,6 +3132,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 1e4d404f02..5033e8c87a 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4540,7 +4540,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index 873e43bfe6..6f53a07108 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -382,6 +386,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -853,6 +896,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3512,6 +3567,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f3c232842d..37e7ad08d8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -62,6 +62,7 @@
 #include "storage/lmgr.h"
 #include "utils/date.h"
 #include "utils/datetime.h"
+#include "utils/jsonb.h"
 #include "utils/numeric.h"
 #include "utils/xml.h"
 
@@ -280,6 +281,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct GroupClause  *groupclause;
 	struct KeyActions	*keyactions;
 	struct KeyAction	*keyaction;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -555,7 +563,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -634,6 +642,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -659,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -669,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -680,12 +755,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -696,9 +771,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -711,7 +787,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -719,17 +795,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -737,7 +813,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -762,7 +838,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -780,6 +856,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -815,11 +892,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -837,6 +918,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -13017,6 +13101,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -13035,6 +13120,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13328,7 +13414,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13403,6 +13489,14 @@ interval_second:
 				}
 		;
 
+/* Mapping of PG jsonb types to SQL/JSON JSON type */
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName(SQLJSON_TYPE_NAME());
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13859,6 +13953,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13941,6 +14075,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14193,6 +14346,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14206,6 +14368,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14493,6 +14656,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15191,6 +15356,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15636,6 +16325,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15676,6 +16366,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15712,10 +16403,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15732,6 +16425,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15763,7 +16457,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15806,6 +16502,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15835,6 +16532,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15864,6 +16562,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15915,6 +16614,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -15972,6 +16672,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -16039,6 +16749,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -16140,6 +16851,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16202,6 +16914,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16254,11 +16967,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16279,6 +16994,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16323,7 +17039,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16380,6 +17108,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16416,6 +17145,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16449,6 +17179,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16483,6 +17214,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16516,6 +17248,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 4133526f04..9db8967c60 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 2d1a477154..678840593b 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,8 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +78,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +320,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3094,3 +3157,1411 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format = JS_FORMAT_JSONB;
+		}
+		else if (have_json)
+		{
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+		else
+		{
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = SQLJSON_TYPE_OID();
+		JsonFormatType format =
+			SQLJSON_TYPE_IS_JSONB() ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 9ce3a0de96..a6113ff910 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1957,6 +1957,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 875de7ba28..683e1ebcfa 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 0e8e065457..0f7646996a 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -23,6 +23,7 @@
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
 #include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/numeric.h"
 #include "utils/syscache.h"
@@ -294,6 +295,14 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "pg_catalog.json" : "json");
+			break;
+
+		case JSONBOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "json" : "jsonb");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index 419469fab5..a623a66766 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1017,11 +1017,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6672,3 +6667,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 30ca2cf6c8..3e5bb37369 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index 8d1e7fbf91..d11683c962 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -90,6 +69,8 @@ static JsonbParseState *clone_parse_state(JsonbParseState *state);
 static char *JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool indent);
 static void add_indent(StringInfo out, bool indent, int level);
 
+int			sql_json_type;		/* GUC for mapping jsonb to SQL/JSON JSON */
+
 /*
  * jsonb type input function
  */
@@ -98,7 +79,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +103,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +144,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +242,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +252,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +288,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +611,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1118,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1171,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1182,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1203,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1231,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1269,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
 }
 
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
+}
+
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1553,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1566,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1615,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1687,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1737,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1753,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1773,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1811,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1875,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1957,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2225,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 5711187795..a4117617d4 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -63,7 +63,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -688,7 +689,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -731,6 +734,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1935,7 +1941,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1945,15 +1951,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 6335845d08..7e1cb032f8 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2771,11 +2771,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3247,6 +3247,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5638,3 +5682,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index fa22546f22..43c9871506 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->val, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 078aaef539..3b596be9fa 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 8da525c715..2e907d54dd 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -63,6 +63,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/hsearch.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
@@ -455,6 +456,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -488,6 +495,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6192,7 +6201,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -8038,6 +8048,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8131,6 +8143,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8154,6 +8167,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8209,6 +8223,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8315,6 +8334,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9490,6 +9624,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->val);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9587,6 +9825,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9732,17 +9971,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == SQLJSON_TYPE_OID()))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9772,13 +10095,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9814,7 +10138,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9828,6 +10162,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9837,6 +10174,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9856,10 +10203,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9883,16 +10232,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9929,6 +10292,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10169,6 +10541,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index f9504d3aec..b357a042e3 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -96,6 +96,7 @@
 #include "utils/bytea.h"
 #include "utils/float.h"
 #include "utils/guc_tables.h"
+#include "utils/jsonb.h"
 #include "utils/memutils.h"
 #include "utils/pg_locale.h"
 #include "utils/pg_lsn.h"
@@ -557,6 +558,12 @@ static const struct config_enum_entry wal_compression_options[] = {
 	{NULL, 0, false}
 };
 
+const struct config_enum_entry sql_json_type_info[] = {
+	{"json", SQLJSON_TYPE_JSON, false},
+	{"jsonb", SQLJSON_TYPE_JSONB, false},
+	{NULL, 0, false}
+};
+
 /*
  * Options for enum values stored in other modules
  */
@@ -5013,6 +5020,18 @@ static struct config_enum ConfigureNamesEnum[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"sql_json", PGC_USERSET, COMPAT_OPTIONS_CLIENT,
+			gettext_noop("Sets what PostgreSQL type to use as an implementaion of SQL JSON type."),
+			gettext_noop("When turned on, jsonb type is mapped to SQL JSON type, "
+						 "json type is mapped to JSON TEXT type.")
+		},
+		&sql_json_type,
+		SQLJSON_TYPE_JSON,
+		sql_json_type_info,
+		NULL, NULL, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, 0, NULL, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index a1acd46b61..c4ca5fa2fa 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -767,6 +767,7 @@
 # - Other Platforms and Clients -
 
 #transform_null_equals = off
+#sql_json = json # jsonb
 
 
 #------------------------------------------------------------------------------
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 9f2cd1f127..9b1252f06d 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(lfirst_node(String, temp)->val);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index fc6d3bfd94..aaf6e20e0b 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -561,14 +561,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 4d992dc224..b4d5738b44 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8726,6 +8726,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8733,10 +8737,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8745,6 +8765,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9617,6 +9650,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9625,10 +9662,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9637,6 +9693,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 6a24341faa..00916724d9 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index cd57a704ad..26a4bd28ee 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index eea87f847d..c1cfbfc6b3 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 7c657c1241..3a37e7a8a6 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -489,6 +499,20 @@ typedef enum NodeTag
 	T_VacuumRelation,
 	T_PublicationObjSpec,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 784164b32a..d4e788ddbf 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1550,6 +1550,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 433437643e..0af3d0bb2f 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1235,6 +1235,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format;		/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f836acf876..458f55fbec 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 93f979f320..c20a6a6d5f 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 7daf09f20e..f16cfdcb71 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4e07debf78..be5cc0e397 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,36 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
+
+/* values for the sql+json_type GUC. */
+typedef enum SqlJsonType
+{
+	SQLJSON_TYPE_JSON = 0,
+	SQLJSON_TYPE_JSONB = 1
+} SqlJsonType;
+
+#define SQLJSON_TYPE_IS_JSONB() (sql_json_type == SQLJSON_TYPE_JSONB)
+#define SQLJSON_TYPE_OID() (SQLJSON_TYPE_IS_JSONB() ? JSONBOID : JSONOID)
+#define SQLJSON_TYPE_NAME() (SQLJSON_TYPE_IS_JSONB() ? "jsonb" : "json")
+
+/* GUC */
+extern int sql_json_type;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +433,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +448,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 0ca48591d0..9e9128e8b2 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 87d302b702..fd2663c22f 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index 1e24801a6f..5a8c2f3eef 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a8571a3ffa..c47dee05cb 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb.out b/src/test/regress/expected/jsonb.out
index a9cd145aec..905b50e850 100644
--- a/src/test/regress/expected/jsonb.out
+++ b/src/test/regress/expected/jsonb.out
@@ -5509,3 +5509,133 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
  12345
 (1 row)
 
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+        Table "public.test_json_as_json"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | json  |           |          | 
+ jb     | jsonb |           |          | 
+
+set sql_json = jsonb;
+select json(' { "aa": 1, "b" : 2 }');
+       json        
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+       jsonb       
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+\d test_json_as_json
+             Table "public.test_json_as_json"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | pg_catalog.json |           |          | 
+ jb     | json            |           |          | 
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+             Table "public.test_json_as_jsonb"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | json            |           |          | 
+ jb     | json            |           |          | 
+ jt     | pg_catalog.json |           |          | 
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(pg_catalog.json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
+set sql_json = json;
+\d test_json_as_jsonb
+        Table "public.test_json_as_jsonb"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | jsonb |           |          | 
+ jb     | jsonb |           |          | 
+ jt     | json  |           |          | 
+
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..f2f5e271b8
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 562b586d8e..e7d6358a25 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..51bd216120
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1352 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Result
+   Output: JSON('123'::pg_catalog.json RETURNING pg_catalog.json)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+    pg_typeof    
+-----------------
+ pg_catalog.json
+(1 row)
+
+SET sql_json = json;
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING pg_catalog.json)
+(2 rows)
+
+SET sql_json = json;
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 5b0c73d7e3..f353e2c1c5 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -112,7 +112,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb.sql b/src/test/regress/sql/jsonb.sql
index 5016f29c15..4af2a0cb11 100644
--- a/src/test/regress/sql/jsonb.sql
+++ b/src/test/regress/sql/jsonb.sql
@@ -1482,3 +1482,41 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
+
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+
+set sql_json = jsonb;
+
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+\d test_json_as_json
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+
+set sql_json = json;
+\d test_json_as_jsonb
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 5a9c479692..7a849ae363 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..4ff6076763
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,467 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+
+SET sql_json = json;
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+
+SET sql_json = json;
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.31.1

0002-JSON_TABLE-v53.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v53.patchDownload
From e05fa3c2cb06ec288783180f899a85c30fa233dc Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 16 Sep 2021 10:31:39 -0400
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  19 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  10 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 467 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 227 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  37 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2885 insertions(+), 32 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 2c84905df1..c127382fe7 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18631,6 +18631,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19301,6 +19306,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 09f5253abb..85d38610ee 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3787,7 +3787,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 094c84008f..8565e46b68 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0d4d30853e..3be81abc91 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4608,6 +4608,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4700,8 +4701,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4837,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	/* Want to execute expressions inside function's memory context */
 	MemoryContextSwitchTo(oldcontext);
 
+
 	PG_TRY();
 	{
 		res = func(op, econtext, res, resnull, p, error);
@@ -4849,6 +4857,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4860,8 +4869,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4987,6 +4998,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index f9fafa9e5b..65f19ea630 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 52422708a1..17496205e1 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1392,6 +1392,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1402,7 +1403,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2664,6 +2667,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5756,6 +5829,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 1ce2ac1076..2904b531c5 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3608,6 +3631,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 97bd0bac6b..eb739f2ee0 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2434,6 +2434,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3445,6 +3447,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4401,6 +4404,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index a45581a8ca..444f1f9a09 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1090,6 +1090,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1100,7 +1101,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1864,6 +1867,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4667,6 +4690,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 6d6b396e42..285fc0969b 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -533,6 +533,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -543,7 +544,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1494,6 +1497,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3150,6 +3177,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 37e7ad08d8..bb9dc9e22f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -669,15 +669,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -691,6 +701,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -698,6 +709,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -772,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -782,8 +795,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -791,7 +804,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -893,7 +906,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -918,6 +931,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12450,6 +12467,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -13001,6 +13031,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeInteger(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15528,6 +15560,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15642,6 +15678,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16485,6 +16668,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16518,6 +16702,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16681,6 +16866,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -17048,6 +17234,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -17085,6 +17272,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -17128,6 +17316,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index 078029ba1f..cea66ec5f8 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,7 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1100,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 678840593b..579c68a929 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4092,7 +4092,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4130,14 +4130,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4438,6 +4437,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..94c96606c1
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,467 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  pasring of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.val = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.val;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index c5c3f26ecf..decb2c2234 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index a6113ff910..1961848825 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1992,6 +1992,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 3b596be9fa..ebfa226bf3 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->val);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 2e907d54dd..e8a1789e38 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -497,6 +497,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8424,7 +8426,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9687,6 +9690,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10935,16 +10941,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -11035,6 +11039,219 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->val));
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 9b1252f06d..fa1374f2fd 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 00916724d9..0abe9d1ee4 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 3a37e7a8a6..ee192fd79d 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -508,6 +510,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d4e788ddbf..a1191a601a 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1563,6 +1563,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1622,6 +1635,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 0af3d0bb2f..da8cd5fbd5 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1243,7 +1252,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1457,6 +1467,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 458f55fbec..15f586d455 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 0eab3c03e8..9216f81acb 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index fd2663c22f..3c37ea087a 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index f2f5e271b8..d89c3bef44 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..6614dd6e45 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index f093605472..b421e58aac 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1234,6 +1234,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2630,6 +2638,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.31.1

0003-JSON_TABLE-PLAN-DEFAULT-clause-v53.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v53.patchDownload
From 6cb61d57dd0395f5a3cf4a29a013152a4420d7a5 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 16 Sep 2021 10:33:01 -0400
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 462 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index c127382fe7..83be7a1013 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19314,6 +19314,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19375,7 +19379,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19388,22 +19393,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parrent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19575,6 +19564,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19597,8 +19590,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 17496205e1..ba67636038 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2679,6 +2679,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2717,6 +2718,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2733,6 +2736,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 2904b531c5..070eaaa551 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -152,6 +152,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -163,6 +165,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 444f1f9a09..f748c36044 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1874,6 +1874,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1885,6 +1887,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 285fc0969b..b4f6c55f1c 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1504,6 +1504,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1517,6 +1519,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index bb9dc9e22f..986111800f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -691,6 +691,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -804,7 +809,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15682,13 +15687,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15825,6 +15832,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16703,6 +16738,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17318,6 +17354,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 94c96606c1..41fe7659de 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -174,12 +174,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -187,7 +188,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -195,8 +196,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -208,7 +210,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -386,6 +388,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index ebfa226bf3..4512c529e7 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index e8a1789e38..ae60d5140c 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11228,6 +11228,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index a1191a601a..f4e9eff9d0 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1655,6 +1655,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1664,6 +1676,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index da8cd5fbd5..be5e0482de 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1476,6 +1476,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1490,6 +1492,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 15f586d455..6065bbae88 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index d89c3bef44..0cd8f73c66 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 6614dd6e45..cd97ff7f46 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index b421e58aac..1d4a69d95f 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1240,6 +1240,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.31.1

0004-JSON_TABLE-PLAN-clause-v53.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v53.patchDownload
From 197401515e0e541096d3a27122f745bd207b1acc Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 4 Jan 2022 08:54:55 -0500
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 322 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1389 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 83be7a1013..3f3a048ce7 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19312,9 +19312,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19338,6 +19339,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19380,7 +19391,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19565,7 +19576,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19592,18 +19603,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19682,6 +19706,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19713,9 +19754,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index ba67636038..67fdfa2b53 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2677,9 +2677,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2697,6 +2697,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2708,6 +2709,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2717,9 +2736,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5839,6 +5858,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 070eaaa551..d198f50059 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -151,9 +151,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 928570b22e..971fe4a548 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -864,6 +864,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index f748c36044..5a1e2a5d20 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1873,9 +1873,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index b4f6c55f1c..917592f757 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1503,9 +1503,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 986111800f..d75d659b31 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -676,6 +676,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -691,8 +703,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15694,7 +15704,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15816,12 +15826,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15833,12 +15846,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 41fe7659de..eae5e699db 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -38,12 +38,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -156,19 +159,154 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -186,34 +324,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -377,19 +559,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -407,7 +650,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -415,9 +660,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -453,7 +720,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.val;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index ae60d5140c..5cd9573339 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11065,10 +11065,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11197,6 +11241,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11228,14 +11274,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index c1cfbfc6b3..018817021a 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index f4e9eff9d0..c2ca0c1237 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1646,6 +1646,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1655,6 +1656,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1667,6 +1679,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1676,7 +1705,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index be5e0482de..efc6afe777 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1475,9 +1475,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0cd8f73c66..9467c4f67c 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' -- AS <path name> required here
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE path names and column names shall be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' -- without root path name
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index cd97ff7f46..be2d65b3ff 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 1d4a69d95f..9abdce87f9 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1240,7 +1240,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.31.1

#64Julien Rouhaud
rjuju123@gmail.com
In reply to: Andrew Dunstan (#63)
Re: SQL/JSON: JSON_TABLE

Hi,

On Tue, Jan 04, 2022 at 09:03:05AM -0500, Andrew Dunstan wrote:

rebased again.

This version conflicts with recent c4cc2850f4d1 (Rename value node fields).
Can you send a rebased version?

#65Andrew Dunstan
andrew@dunslane.net
In reply to: Julien Rouhaud (#64)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 1/18/22 01:32, Julien Rouhaud wrote:

Hi,

On Tue, Jan 04, 2022 at 09:03:05AM -0500, Andrew Dunstan wrote:

rebased again.

This version conflicts with recent c4cc2850f4d1 (Rename value node fields).
Can you send a rebased version?

attached

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-v54.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-v54.patchDownload
From 6c9af24d1c958ba8eb609a273fb47ec7fc7e7606 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 18 Jan 2022 15:06:00 -0500
Subject: [PATCH 1/4] SQL-JSON-functions

---
 doc/src/sgml/config.sgml                      |   19 +
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  767 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1471 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    9 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  352 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  437 +++-
 src/backend/utils/misc/guc.c                  |   19 +
 src/backend/utils/misc/postgresql.conf.sample |    1 +
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   47 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb.out           |  130 ++
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1352 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb.sql                |   38 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  467 ++++
 59 files changed, 13151 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 4cd9818acf..4fda095cdb 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -9735,6 +9735,25 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir'
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-sql-json" xreflabel="sql_json">
+      <term><varname>sql_json</varname> (<type>enum</type>)
+      <indexterm><primary>json</primary></indexterm>
+      <indexterm><primary>jsonb</primary></indexterm>
+      <indexterm>
+       <primary><varname>sql_json</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+         Valid values are <literal>json</literal> and <literal>jsonb</literal>.
+         Specifies what <productname>PostgreSQL</productname> type is used
+         as an implementation of SQL type <type>JSON</type>.
+         When <varname>sql_json</varname> is set to <literal>jsonb</literal>,
+         <productname>PostgreSQL</productname> type <type>json</type> can be
+         accessed using explicit qualification <type>pg_catalog.json</type>.
+       </para>
+      </listitem>
+     </varlistentry>
      </variablelist>
     </sect2>
    </sect1>
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index a270f89dfe..d99b29ae66 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17563,6 +17563,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19716,6 +21634,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 847357bf80..2e8fbf4f57 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->sval);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d6f7d7c2d7..6ac6b5ee8d 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4386,3 +4503,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index bd86f546d7..9c8f341d96 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index d5191cf02b..b2bda86889 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 90b5da51c9..51e6b8058b 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2298,6 +2298,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5337,6 +5704,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 06345da3ba..46dd562115 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3347,6 +3583,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3924,6 +4193,30 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 822395625b..40523eec79 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -817,3 +818,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 47d0564fa2..e8de1dd3aa 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2348,6 +2456,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2678,6 +2858,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3309,6 +3490,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -4017,6 +4293,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 2b0236937a..abfb3df04c 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1751,6 +1751,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4535,6 +4649,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3f68f7c18d..1881ba64c2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1389,6 +1389,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2974,6 +3133,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 8dc7dd4ca2..c7b9d8d11a 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4540,7 +4540,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index a707dc9f26..a37b2c76f5 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -382,6 +386,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -853,6 +896,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3512,6 +3567,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index b5966712ce..00f90eeb5b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -62,6 +62,7 @@
 #include "storage/lmgr.h"
 #include "utils/date.h"
 #include "utils/datetime.h"
+#include "utils/jsonb.h"
 #include "utils/numeric.h"
 #include "utils/xml.h"
 
@@ -280,6 +281,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct GroupClause  *groupclause;
 	struct KeyActions	*keyactions;
 	struct KeyAction	*keyaction;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -555,7 +563,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -634,6 +642,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -659,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -669,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -680,12 +755,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -696,9 +771,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -711,7 +787,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -719,17 +795,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -737,7 +813,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -762,7 +838,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -780,6 +856,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -815,11 +892,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -837,6 +918,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -13017,6 +13101,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -13035,6 +13120,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13328,7 +13414,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13403,6 +13489,14 @@ interval_second:
 				}
 		;
 
+/* Mapping of PG jsonb types to SQL/JSON JSON type */
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName(SQLJSON_TYPE_NAME());
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13859,6 +13953,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13941,6 +14075,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14193,6 +14346,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14206,6 +14368,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14493,6 +14656,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15191,6 +15356,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15636,6 +16325,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15676,6 +16366,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15712,10 +16403,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15732,6 +16425,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15763,7 +16457,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15806,6 +16502,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15835,6 +16532,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15864,6 +16562,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15915,6 +16614,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -15972,6 +16672,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -16039,6 +16749,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -16140,6 +16851,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16202,6 +16914,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16254,11 +16967,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16279,6 +16994,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16323,7 +17039,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16380,6 +17108,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16416,6 +17145,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16449,6 +17179,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16483,6 +17214,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16516,6 +17248,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 6c793b72ec..2e549e7b39 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index c4aaf37727..8ba09dd1c1 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,8 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +78,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +320,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3094,3 +3157,1411 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format = JS_FORMAT_JSONB;
+		}
+		else if (have_json)
+		{
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+		else
+		{
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = SQLJSON_TYPE_OID();
+		JsonFormatType format =
+			SQLJSON_TYPE_IS_JSONB() ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 059eeb9e94..829c0f9497 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1957,6 +1957,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 50227cc098..eee0a29c08 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 2918fdbfb6..fe1627dedc 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -23,6 +23,7 @@
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
 #include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/numeric.h"
 #include "utils/syscache.h"
@@ -294,6 +295,14 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "pg_catalog.json" : "json");
+			break;
+
+		case JSONBOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "json" : "jsonb");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index e8f996ac83..35db7e44e5 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1017,11 +1017,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6672,3 +6667,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 7879f342e6..492796eb83 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index f5f40a94bd..9089b3b22e 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -90,6 +69,8 @@ static JsonbParseState *clone_parse_state(JsonbParseState *state);
 static char *JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool indent);
 static void add_indent(StringInfo out, bool indent, int level);
 
+int			sql_json_type;		/* GUC for mapping jsonb to SQL/JSON JSON */
+
 /*
  * jsonb type input function
  */
@@ -98,7 +79,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +103,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +144,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +242,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +252,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +288,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +611,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1118,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1171,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1182,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1203,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1231,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1269,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
 }
 
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
+}
+
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1553,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1566,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1615,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1687,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1737,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1753,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1773,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1811,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1875,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1957,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2225,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 291fb722e2..5e9dbdcc45 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -63,7 +63,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -688,7 +689,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -731,6 +734,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1935,7 +1941,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1945,15 +1951,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 0273f883d4..69b4977399 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2771,11 +2771,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3247,6 +3247,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5638,3 +5682,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index 9be4e305ff..ca1cfe3d36 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->sval, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index eff3734b6a..7811fa31e0 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 039b1d2b95..45e2b8ab62 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -63,6 +63,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/hsearch.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
@@ -457,6 +458,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -490,6 +497,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6236,7 +6245,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -8082,6 +8092,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8175,6 +8187,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8198,6 +8211,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8253,6 +8267,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8359,6 +8378,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9518,6 +9652,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->sval);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9641,6 +9879,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9786,17 +10025,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == SQLJSON_TYPE_OID()))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9826,13 +10149,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9868,7 +10192,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9882,6 +10216,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9891,6 +10228,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9910,10 +10257,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9937,16 +10286,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9983,6 +10346,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10223,6 +10595,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index 4c94f09c64..1e36b5b4ac 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -97,6 +97,7 @@
 #include "utils/bytea.h"
 #include "utils/float.h"
 #include "utils/guc_tables.h"
+#include "utils/jsonb.h"
 #include "utils/memutils.h"
 #include "utils/pg_locale.h"
 #include "utils/pg_lsn.h"
@@ -558,6 +559,12 @@ static const struct config_enum_entry wal_compression_options[] = {
 	{NULL, 0, false}
 };
 
+const struct config_enum_entry sql_json_type_info[] = {
+	{"json", SQLJSON_TYPE_JSON, false},
+	{"jsonb", SQLJSON_TYPE_JSONB, false},
+	{NULL, 0, false}
+};
+
 /*
  * Options for enum values stored in other modules
  */
@@ -5025,6 +5032,18 @@ static struct config_enum ConfigureNamesEnum[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"sql_json", PGC_USERSET, COMPAT_OPTIONS_CLIENT,
+			gettext_noop("Sets what PostgreSQL type to use as an implementaion of SQL JSON type."),
+			gettext_noop("When turned on, jsonb type is mapped to SQL JSON type, "
+						 "json type is mapped to JSON TEXT type.")
+		},
+		&sql_json_type,
+		SQLJSON_TYPE_JSON,
+		sql_json_type_info,
+		NULL, NULL, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, 0, NULL, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 817d5f5324..72b54a4da9 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -768,6 +768,7 @@
 # - Other Platforms and Clients -
 
 #transform_null_equals = off
+#sql_json = json # jsonb
 
 
 #------------------------------------------------------------------------------
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index a67487e5fe..7120836c70 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(lfirst_node(String, temp)->sval);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index 137f6eef69..71946ba35f 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -561,14 +561,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index b6f689e8d1..c4f8c71a2a 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8726,6 +8726,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8733,10 +8737,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8745,6 +8765,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9617,6 +9650,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9625,10 +9662,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9637,6 +9693,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 56a89ebafb..9ce8df17e5 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 344399f6a8..538d7eca07 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index fe173101d1..3e252067a9 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index f9ddafd345..9d907afb2f 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -490,6 +500,20 @@ typedef enum NodeTag
 	T_VacuumRelation,
 	T_PublicationObjSpec,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 3e9bdc781f..27ec40dd7f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1551,6 +1551,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index dab5c4ff5d..09347e2db7 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1235,6 +1235,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format;		/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index bcef7eed2f..ab3d8e0b52 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 851e787bfd..0a22af80a2 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 8a84a0cdb4..da4a9257b3 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4cbe6edf21..7534c2e7d1 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,36 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
+
+/* values for the sql+json_type GUC. */
+typedef enum SqlJsonType
+{
+	SQLJSON_TYPE_JSON = 0,
+	SQLJSON_TYPE_JSONB = 1
+} SqlJsonType;
+
+#define SQLJSON_TYPE_IS_JSONB() (sql_json_type == SQLJSON_TYPE_JSONB)
+#define SQLJSON_TYPE_OID() (SQLJSON_TYPE_IS_JSONB() ? JSONBOID : JSONOID)
+#define SQLJSON_TYPE_NAME() (SQLJSON_TYPE_IS_JSONB() ? "jsonb" : "json")
+
+/* GUC */
+extern int sql_json_type;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +433,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +448,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 865b2ff7c1..62dc3d88a4 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index cd0b5d5b61..98a61d7f72 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index dee6b8200d..5ec511fd01 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a44e07a17a..5e2b606f9b 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb.out b/src/test/regress/expected/jsonb.out
index a9cd145aec..905b50e850 100644
--- a/src/test/regress/expected/jsonb.out
+++ b/src/test/regress/expected/jsonb.out
@@ -5509,3 +5509,133 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
  12345
 (1 row)
 
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+        Table "public.test_json_as_json"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | json  |           |          | 
+ jb     | jsonb |           |          | 
+
+set sql_json = jsonb;
+select json(' { "aa": 1, "b" : 2 }');
+       json        
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+       jsonb       
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+\d test_json_as_json
+             Table "public.test_json_as_json"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | pg_catalog.json |           |          | 
+ jb     | json            |           |          | 
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+             Table "public.test_json_as_jsonb"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | json            |           |          | 
+ jb     | json            |           |          | 
+ jt     | pg_catalog.json |           |          | 
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(pg_catalog.json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
+set sql_json = json;
+\d test_json_as_jsonb
+        Table "public.test_json_as_jsonb"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | jsonb |           |          | 
+ jb     | jsonb |           |          | 
+ jt     | json  |           |          | 
+
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..f2f5e271b8
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 562b586d8e..e7d6358a25 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..51bd216120
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1352 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Result
+   Output: JSON('123'::pg_catalog.json RETURNING pg_catalog.json)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+    pg_typeof    
+-----------------
+ pg_catalog.json
+(1 row)
+
+SET sql_json = json;
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING pg_catalog.json)
+(2 rows)
+
+SET sql_json = json;
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 5b0c73d7e3..f353e2c1c5 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -112,7 +112,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb.sql b/src/test/regress/sql/jsonb.sql
index 5016f29c15..4af2a0cb11 100644
--- a/src/test/regress/sql/jsonb.sql
+++ b/src/test/regress/sql/jsonb.sql
@@ -1482,3 +1482,41 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
+
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+
+set sql_json = jsonb;
+
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+\d test_json_as_json
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+
+set sql_json = json;
+\d test_json_as_jsonb
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 5a9c479692..7a849ae363 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..4ff6076763
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,467 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+
+SET sql_json = json;
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+
+SET sql_json = json;
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.31.1

0002-JSON_TABLE-v54.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v54.patchDownload
From 7ae87ad924263a01a86d972c99e06f0f0e247d4c Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 18 Jan 2022 16:04:49 -0500
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  19 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  10 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 467 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 228 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  37 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2886 insertions(+), 32 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index d99b29ae66..04b8585438 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18631,6 +18631,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19301,6 +19306,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index b970997c34..eacbc44a04 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3787,7 +3787,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 2e8fbf4f57..cff0e58bb4 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 6ac6b5ee8d..ac4edbeb7b 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4608,6 +4608,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4700,8 +4701,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4837,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	/* Want to execute expressions inside function's memory context */
 	MemoryContextSwitchTo(oldcontext);
 
+
 	PG_TRY();
 	{
 		res = func(op, econtext, res, resnull, p, error);
@@ -4849,6 +4857,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4860,8 +4869,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4987,6 +4998,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 0db4ed0c2f..691c3e28ce 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 51e6b8058b..f173107624 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1393,6 +1393,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1403,7 +1404,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2665,6 +2668,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5770,6 +5843,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 46dd562115..d9048a4699 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3616,6 +3639,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index e8de1dd3aa..cbae180dba 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2454,6 +2454,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3487,6 +3489,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4444,6 +4447,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index abfb3df04c..7250f295a2 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1091,6 +1091,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1101,7 +1102,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1865,6 +1868,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4676,6 +4699,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 1881ba64c2..f4d0173142 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -533,6 +533,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -543,7 +544,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1494,6 +1497,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3151,6 +3178,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 00f90eeb5b..f61ce6e0cf 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -669,15 +669,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -691,6 +701,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -698,6 +709,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -772,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -782,8 +795,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -791,7 +804,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -893,7 +906,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -918,6 +931,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12450,6 +12467,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -13001,6 +13031,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15528,6 +15560,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15642,6 +15678,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16485,6 +16668,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16518,6 +16702,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16681,6 +16866,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -17048,6 +17234,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -17085,6 +17272,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -17128,6 +17316,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index d8b14ba7cd..9d27535f97 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,7 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1100,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8ba09dd1c1..d3bb30afac 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4092,7 +4092,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4130,14 +4130,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4438,6 +4437,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..98d228b030
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,467 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  pasring of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.sval = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index cb9e177b5e..e06c23d0de 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 829c0f9497..7cc5020861 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1992,6 +1992,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 7811fa31e0..f0078b7874 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->sval);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 45e2b8ab62..1c622407fe 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -499,6 +499,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8468,7 +8470,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9715,6 +9718,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10989,16 +10995,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -11089,6 +11093,220 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->sval)
+				);
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 7120836c70..2ffa014618 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 9ce8df17e5..9df70e6f06 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 9d907afb2f..09ad2769b8 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -509,6 +511,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 27ec40dd7f..b33a9c13ba 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1564,6 +1564,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1623,6 +1636,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 09347e2db7..17fb6d8120 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1243,7 +1252,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1457,6 +1467,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index ab3d8e0b52..c7365706a3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 2495c30034..e86b002392 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 98a61d7f72..1897ddffa6 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index f2f5e271b8..d89c3bef44 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..6614dd6e45 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 89249ecc97..ba0978cf7c 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1234,6 +1234,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2630,6 +2638,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.31.1

0003-JSON_TABLE-PLAN-DEFAULT-clause-v54.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v54.patchDownload
From 406b1ddb4d4ca44790bbb488e149b87362e51960 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 18 Jan 2022 16:05:42 -0500
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 462 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 04b8585438..a765510b37 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19314,6 +19314,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19375,7 +19379,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19388,22 +19393,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parrent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19575,6 +19564,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19597,8 +19590,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index f173107624..250909542f 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2680,6 +2680,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2718,6 +2719,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2734,6 +2737,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index d9048a4699..ff9bf1c8e8 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -152,6 +152,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -163,6 +165,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 7250f295a2..36f03c2ab2 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1875,6 +1875,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1886,6 +1888,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index f4d0173142..6baaebc6fc 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1504,6 +1504,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1517,6 +1519,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f61ce6e0cf..87ddcb0912 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -691,6 +691,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -804,7 +809,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15682,13 +15687,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15825,6 +15832,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16703,6 +16738,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17318,6 +17354,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 98d228b030..db772995ac 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -174,12 +174,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -187,7 +188,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -195,8 +196,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -208,7 +210,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -386,6 +388,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index f0078b7874..f850392ab3 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 1c622407fe..287a77e6e5 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11283,6 +11283,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b33a9c13ba..6dd52c59c1 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1656,6 +1656,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1665,6 +1677,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 17fb6d8120..9f82a272e2 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1476,6 +1476,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1490,6 +1492,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c7365706a3..ac17889517 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index d89c3bef44..0cd8f73c66 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 6614dd6e45..cd97ff7f46 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index ba0978cf7c..25d94f7163 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1240,6 +1240,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.31.1

0004-JSON_TABLE-PLAN-clause-v54.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v54.patchDownload
From cf8f2ae989a90b0fc386af4837e871efde8f9698 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 18 Jan 2022 16:06:50 -0500
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 322 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1389 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index a765510b37..51d5c69418 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19312,9 +19312,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19338,6 +19339,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19380,7 +19391,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19565,7 +19576,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19592,18 +19603,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19682,6 +19706,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19713,9 +19754,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 250909542f..9a6dafe199 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2678,9 +2678,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2698,6 +2698,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2709,6 +2710,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2718,9 +2737,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5853,6 +5872,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index ff9bf1c8e8..cc8c9e1d5b 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -151,9 +151,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 40523eec79..d283cd4239 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -866,6 +866,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 36f03c2ab2..98ef7eae1c 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1874,9 +1874,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 6baaebc6fc..960ffd9066 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1503,9 +1503,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 87ddcb0912..9ad42fe166 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -676,6 +676,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -691,8 +703,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15694,7 +15704,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15816,12 +15826,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15833,12 +15846,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index db772995ac..f4234f4e48 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -38,12 +38,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -156,19 +159,154 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -186,34 +324,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -377,19 +559,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -407,7 +650,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -415,9 +660,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -453,7 +720,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 287a77e6e5..1ad77fe904 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11119,10 +11119,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11251,6 +11295,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11283,14 +11329,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 3e252067a9..1a0833ef11 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 6dd52c59c1..b23823e181 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1647,6 +1647,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1656,6 +1657,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1668,6 +1680,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1677,7 +1706,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 9f82a272e2..60abcb8f66 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1475,9 +1475,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0cd8f73c66..9467c4f67c 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' -- AS <path name> required here
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE path names and column names shall be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' -- without root path name
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index cd97ff7f46..be2d65b3ff 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 25d94f7163..d4a6e5f687 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1240,7 +1240,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.31.1

#66Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#65)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 1/18/22 16:23, Andrew Dunstan wrote:

On 1/18/22 01:32, Julien Rouhaud wrote:

Hi,

On Tue, Jan 04, 2022 at 09:03:05AM -0500, Andrew Dunstan wrote:

rebased again.

This version conflicts with recent c4cc2850f4d1 (Rename value node fields).
Can you send a rebased version?

attached

rebased with some review comments attended to.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-v55.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-v55.patchDownload
From 9d44e65c8594a6abcfc932bbe2a0c0138db7f005 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 1 Feb 2022 11:34:19 -0500
Subject: [PATCH 1/4] SQL/JSON functions

---
 doc/src/sgml/config.sgml                      |   19 +
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  767 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1468 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    9 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  352 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  437 +++-
 src/backend/utils/misc/guc.c                  |   19 +
 src/backend/utils/misc/postgresql.conf.sample |    1 +
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   47 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb.out           |  130 ++
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1352 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb.sql                |   38 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  467 ++++
 59 files changed, 13148 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 692d8a2a17..f59ef4a6dd 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -9735,6 +9735,25 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir'
       </listitem>
      </varlistentry>
 
+     <varlistentry id="guc-sql-json" xreflabel="sql_json">
+      <term><varname>sql_json</varname> (<type>enum</type>)
+      <indexterm><primary>json</primary></indexterm>
+      <indexterm><primary>jsonb</primary></indexterm>
+      <indexterm>
+       <primary><varname>sql_json</varname> configuration parameter</primary>
+      </indexterm>
+      </term>
+      <listitem>
+       <para>
+         Valid values are <literal>json</literal> and <literal>jsonb</literal>.
+         Specifies what <productname>PostgreSQL</productname> type is used
+         as an implementation of SQL type <type>JSON</type>.
+         When <varname>sql_json</varname> is set to <literal>jsonb</literal>,
+         <productname>PostgreSQL</productname> type <type>json</type> can be
+         accessed using explicit qualification <type>pg_catalog.json</type>.
+       </para>
+      </listitem>
+     </varlistentry>
      </variablelist>
     </sect2>
    </sect1>
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 8754f2f89b..5b8b934c51 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17564,6 +17564,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19719,6 +21637,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 847357bf80..25253f5377 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->sval);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d6f7d7c2d7..0483279f91 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4386,3 +4503,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format_type == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index bd86f546d7..9c8f341d96 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index d5191cf02b..b2bda86889 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 90b5da51c9..8cdcf5d13b 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2298,6 +2298,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format_type);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5337,6 +5704,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 06345da3ba..3d77cacecb 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format_type);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3347,6 +3583,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3924,6 +4193,30 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 822395625b..51faa0636c 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -817,3 +818,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format_type = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 47d0564fa2..e8de1dd3aa 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2348,6 +2456,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2678,6 +2858,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3309,6 +3490,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -4017,6 +4293,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 2b0236937a..091d8a4015 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1751,6 +1751,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format_type, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4535,6 +4649,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3f68f7c18d..c15e81a362 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1389,6 +1389,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format_type, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2974,6 +3133,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 8dc7dd4ca2..c7b9d8d11a 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4540,7 +4540,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index a707dc9f26..eef4381477 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -382,6 +386,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		const JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -853,6 +896,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3512,6 +3567,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index b5966712ce..00f90eeb5b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -62,6 +62,7 @@
 #include "storage/lmgr.h"
 #include "utils/date.h"
 #include "utils/datetime.h"
+#include "utils/jsonb.h"
 #include "utils/numeric.h"
 #include "utils/xml.h"
 
@@ -280,6 +281,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct GroupClause  *groupclause;
 	struct KeyActions	*keyactions;
 	struct KeyAction	*keyaction;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -555,7 +563,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -634,6 +642,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -659,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -669,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -680,12 +755,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -696,9 +771,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -711,7 +787,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -719,17 +795,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -737,7 +813,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -762,7 +838,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -780,6 +856,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -815,11 +892,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -837,6 +918,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -13017,6 +13101,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -13035,6 +13120,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13328,7 +13414,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13403,6 +13489,14 @@ interval_second:
 				}
 		;
 
+/* Mapping of PG jsonb types to SQL/JSON JSON type */
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName(SQLJSON_TYPE_NAME());
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13859,6 +13953,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13941,6 +14075,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14193,6 +14346,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14206,6 +14368,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14493,6 +14656,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15191,6 +15356,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15636,6 +16325,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15676,6 +16366,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15712,10 +16403,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15732,6 +16425,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15763,7 +16457,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15806,6 +16502,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15835,6 +16532,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15864,6 +16562,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15915,6 +16614,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -15972,6 +16672,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -16039,6 +16749,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -16140,6 +16851,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16202,6 +16914,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16254,11 +16967,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16279,6 +16994,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16323,7 +17039,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16380,6 +17108,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16416,6 +17145,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16449,6 +17179,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16483,6 +17214,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16516,6 +17248,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 6c793b72ec..2e549e7b39 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 1c09ea24cd..8644eb2e74 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,8 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +78,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +320,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3099,3 +3162,1408 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format_type == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format_type != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format_type;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format_type == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format_type != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format_type == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format_type =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format_type = JS_FORMAT_JSONB;
+		}
+		else
+		{
+			/* Note: this includes the have_json case */
+			
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format_type = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format_type == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format_type == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format_type == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = SQLJSON_TYPE_OID();
+		JsonFormatType format =
+			SQLJSON_TYPE_IS_JSONB() ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 059eeb9e94..829c0f9497 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1957,6 +1957,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 50227cc098..eee0a29c08 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 2918fdbfb6..fe1627dedc 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -23,6 +23,7 @@
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
 #include "utils/fmgroids.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/numeric.h"
 #include "utils/syscache.h"
@@ -294,6 +295,14 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "pg_catalog.json" : "json");
+			break;
+
+		case JSONBOID:
+			buf = pstrdup(SQLJSON_TYPE_IS_JSONB() ? "json" : "jsonb");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index d4c2e7b069..fb395b6f78 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1017,11 +1017,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6666,3 +6661,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 7879f342e6..492796eb83 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index f5f40a94bd..9089b3b22e 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -90,6 +69,8 @@ static JsonbParseState *clone_parse_state(JsonbParseState *state);
 static char *JsonbToCStringWorker(StringInfo out, JsonbContainer *in, int estimated_len, bool indent);
 static void add_indent(StringInfo out, bool indent, int level);
 
+int			sql_json_type;		/* GUC for mapping jsonb to SQL/JSON JSON */
+
 /*
  * jsonb type input function
  */
@@ -98,7 +79,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +103,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +144,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +242,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +252,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +288,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +611,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1118,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1171,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1182,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1203,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1231,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1269,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
 }
 
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
+}
+
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1553,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1566,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1615,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1687,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1737,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1753,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1773,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1811,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1875,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1957,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2225,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 291fb722e2..5e9dbdcc45 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -63,7 +63,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -688,7 +689,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -731,6 +734,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1935,7 +1941,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1945,15 +1951,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 0273f883d4..69b4977399 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2771,11 +2771,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3247,6 +3247,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5638,3 +5682,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index 9be4e305ff..ca1cfe3d36 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->sval, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index eff3734b6a..7811fa31e0 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 039b1d2b95..fc3617f550 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -63,6 +63,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/hsearch.h"
+#include "utils/jsonb.h"
 #include "utils/lsyscache.h"
 #include "utils/partcache.h"
 #include "utils/rel.h"
@@ -457,6 +458,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -490,6 +497,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6236,7 +6245,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -8082,6 +8092,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8175,6 +8187,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8198,6 +8211,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8253,6 +8267,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8359,6 +8378,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format_type == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format_type == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format_type !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9518,6 +9652,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->sval);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9641,6 +9879,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9786,17 +10025,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == SQLJSON_TYPE_OID()))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9826,13 +10149,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9868,7 +10192,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9882,6 +10216,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9891,6 +10228,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9910,10 +10257,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9937,16 +10286,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9983,6 +10346,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10223,6 +10595,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index b3fd42e0f1..5ca946fb9b 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -97,6 +97,7 @@
 #include "utils/bytea.h"
 #include "utils/float.h"
 #include "utils/guc_tables.h"
+#include "utils/jsonb.h"
 #include "utils/memutils.h"
 #include "utils/pg_locale.h"
 #include "utils/pg_lsn.h"
@@ -558,6 +559,12 @@ static const struct config_enum_entry wal_compression_options[] = {
 	{NULL, 0, false}
 };
 
+const struct config_enum_entry sql_json_type_info[] = {
+	{"json", SQLJSON_TYPE_JSON, false},
+	{"jsonb", SQLJSON_TYPE_JSONB, false},
+	{NULL, 0, false}
+};
+
 /*
  * Options for enum values stored in other modules
  */
@@ -5025,6 +5032,18 @@ static struct config_enum ConfigureNamesEnum[] =
 		NULL, NULL, NULL
 	},
 
+	{
+		{"sql_json", PGC_USERSET, COMPAT_OPTIONS_CLIENT,
+			gettext_noop("Sets what PostgreSQL type to use as an implementaion of SQL JSON type."),
+			gettext_noop("When turned on, jsonb type is mapped to SQL JSON type, "
+						 "json type is mapped to JSON TEXT type.")
+		},
+		&sql_json_type,
+		SQLJSON_TYPE_JSON,
+		sql_json_type_info,
+		NULL, NULL, NULL
+	},
+
 	/* End-of-list marker */
 	{
 		{NULL, 0, 0, NULL, NULL}, NULL, 0, NULL, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 817d5f5324..72b54a4da9 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -768,6 +768,7 @@
 # - Other Platforms and Clients -
 
 #transform_null_equals = off
+#sql_json = json # jsonb
 
 
 #------------------------------------------------------------------------------
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index a67487e5fe..7120836c70 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(lfirst_node(String, temp)->sval);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index 137f6eef69..71946ba35f 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -561,14 +561,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 7024dbe10a..9a2dc449d8 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8731,6 +8731,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8738,10 +8742,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8750,6 +8770,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9622,6 +9655,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9630,10 +9667,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9642,6 +9698,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 56a89ebafb..9ce8df17e5 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 344399f6a8..538d7eca07 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index fe173101d1..3e252067a9 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index da35f2c272..4e81a3e859 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -490,6 +500,20 @@ typedef enum NodeTag
 	T_VacuumRelation,
 	T_PublicationObjSpec,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 3e9bdc781f..27ec40dd7f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1551,6 +1551,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index dab5c4ff5d..90108befeb 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1235,6 +1235,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format_type;	/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index bcef7eed2f..ab3d8e0b52 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 851e787bfd..0a22af80a2 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 8a84a0cdb4..da4a9257b3 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4cbe6edf21..7534c2e7d1 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,36 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
+
+/* values for the sql+json_type GUC. */
+typedef enum SqlJsonType
+{
+	SQLJSON_TYPE_JSON = 0,
+	SQLJSON_TYPE_JSONB = 1
+} SqlJsonType;
+
+#define SQLJSON_TYPE_IS_JSONB() (sql_json_type == SQLJSON_TYPE_JSONB)
+#define SQLJSON_TYPE_OID() (SQLJSON_TYPE_IS_JSONB() ? JSONBOID : JSONOID)
+#define SQLJSON_TYPE_NAME() (SQLJSON_TYPE_IS_JSONB() ? "jsonb" : "json")
+
+/* GUC */
+extern int sql_json_type;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +433,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +448,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 865b2ff7c1..62dc3d88a4 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index cd0b5d5b61..98a61d7f72 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index dee6b8200d..5ec511fd01 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a44e07a17a..5e2b606f9b 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb.out b/src/test/regress/expected/jsonb.out
index a9cd145aec..905b50e850 100644
--- a/src/test/regress/expected/jsonb.out
+++ b/src/test/regress/expected/jsonb.out
@@ -5509,3 +5509,133 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
  12345
 (1 row)
 
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+        Table "public.test_json_as_json"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | json  |           |          | 
+ jb     | jsonb |           |          | 
+
+set sql_json = jsonb;
+select json(' { "aa": 1, "b" : 2 }');
+       json        
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select json ' { "aa": 1, "b" : 2 }';
+       jsonb       
+-------------------
+ {"b": 2, "aa": 1}
+(1 row)
+
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+         json          
+-----------------------
+  { "aa": 1, "b" : 2 }
+(1 row)
+
+\d test_json_as_json
+             Table "public.test_json_as_json"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | pg_catalog.json |           |          | 
+ jb     | json            |           |          | 
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+             Table "public.test_json_as_jsonb"
+ Column |      Type       | Collation | Nullable | Default 
+--------+-----------------+-----------+----------+---------
+ js     | json            |           |          | 
+ jb     | json            |           |          | 
+ jt     | pg_catalog.json |           |          | 
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(pg_catalog.json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
+set sql_json = json;
+\d test_json_as_jsonb
+        Table "public.test_json_as_jsonb"
+ Column | Type  | Collation | Nullable | Default 
+--------+-------+-----------+----------+---------
+ js     | jsonb |           |          | 
+ jb     | jsonb |           |          | 
+ jt     | json  |           |          | 
+
+select * from test_json_as_jsonb;
+    js    |    jb    |     jt      
+----------+----------+-------------
+ {"a": 1} | {"a": 1} | { "a" : 1 }
+(1 row)
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+ jsonb_object_field 
+--------------------
+ 1
+(1 row)
+
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+ERROR:  function jsonb_object_field(json, unknown) does not exist
+LINE 1: select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+ json_object_field 
+-------------------
+ 1
+(1 row)
+
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..f2f5e271b8
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 562b586d8e..e7d6358a25 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..51bd216120
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1352 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Result
+   Output: JSON('123'::pg_catalog.json RETURNING pg_catalog.json)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+    pg_typeof    
+-----------------
+ pg_catalog.json
+(1 row)
+
+SET sql_json = json;
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+SET sql_json = jsonb;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING pg_catalog.json)
+(2 rows)
+
+SET sql_json = json;
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 861c30a73a..fdb3fbcb17 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -112,7 +112,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb.sql b/src/test/regress/sql/jsonb.sql
index 5016f29c15..4af2a0cb11 100644
--- a/src/test/regress/sql/jsonb.sql
+++ b/src/test/regress/sql/jsonb.sql
@@ -1482,3 +1482,41 @@ select '12345.0000000000000000000000000000000000000000000005'::jsonb::float8;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int2;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int4;
 select '12345.0000000000000000000000000000000000000000000005'::jsonb::int8;
+
+-- test mapping of jsonb to SQL/JSON JSON type
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+create table test_json_as_json (js json, jb jsonb);
+\d test_json_as_json
+
+set sql_json = jsonb;
+
+select json(' { "aa": 1, "b" : 2 }');
+select json ' { "aa": 1, "b" : 2 }';
+select pg_catalog.json ' { "aa": 1, "b" : 2 }';
+
+\d test_json_as_json
+
+create table test_json_as_jsonb (js json, jb jsonb, jt pg_catalog.json);
+\d test_json_as_jsonb
+
+insert into test_json_as_jsonb values ('{ "a" : 1 }', '{ "a" : 1 }', '{ "a" : 1 }');
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
+
+set sql_json = json;
+\d test_json_as_jsonb
+
+select * from test_json_as_jsonb;
+
+select jsonb_object_field(js, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jb, 'a') from test_json_as_jsonb;
+select jsonb_object_field(jt, 'a') from test_json_as_jsonb;
+select json_object_field(jt, 'a') from test_json_as_jsonb;
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 5a9c479692..7a849ae363 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..4ff6076763
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,467 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING pg_catalog.json);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+SELECT pg_typeof(JSON('123' RETURNING pg_catalog.json));
+
+SET sql_json = json;
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+SET sql_json = jsonb;
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING pg_catalog.json);
+
+SET sql_json = json;
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.1

0002-JSON_TABLE-v55.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v55.patchDownload
From b048c088cdd57f49d6dd0ae23e0fdd8d7dc69a20 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 1 Feb 2022 12:13:35 -0500
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  19 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  10 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 467 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 228 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  37 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2886 insertions(+), 32 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 5b8b934c51..3df418458c 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18632,6 +18632,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19302,6 +19307,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Gerenates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index b970997c34..eacbc44a04 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3787,7 +3787,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 25253f5377..c929cc2d90 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0483279f91..38e0854ff2 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4608,6 +4608,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4700,8 +4701,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4837,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	/* Want to execute expressions inside function's memory context */
 	MemoryContextSwitchTo(oldcontext);
 
+
 	PG_TRY();
 	{
 		res = func(op, econtext, res, resnull, p, error);
@@ -4849,6 +4857,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4860,8 +4869,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4987,6 +4998,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 0db4ed0c2f..691c3e28ce 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 8cdcf5d13b..d6f05bd58d 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1393,6 +1393,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1403,7 +1404,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2665,6 +2668,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5770,6 +5843,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 3d77cacecb..4810ea74f3 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3616,6 +3639,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index e8de1dd3aa..cbae180dba 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2454,6 +2454,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3487,6 +3489,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4444,6 +4447,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 091d8a4015..acbb4ebced 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1091,6 +1091,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1101,7 +1102,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1865,6 +1868,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4676,6 +4699,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c15e81a362..d82fc22cd6 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -533,6 +533,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -543,7 +544,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1494,6 +1497,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3151,6 +3178,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 00f90eeb5b..f61ce6e0cf 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -669,15 +669,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -691,6 +701,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -698,6 +709,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -772,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -782,8 +795,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -791,7 +804,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -893,7 +906,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -918,6 +931,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12450,6 +12467,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -13001,6 +13031,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15528,6 +15560,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15642,6 +15678,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior shall not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16485,6 +16668,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16518,6 +16702,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16681,6 +16866,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -17048,6 +17234,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -17085,6 +17272,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -17128,6 +17316,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index d8b14ba7cd..9d27535f97 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,7 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1100,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8644eb2e74..0406dc2708 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4094,7 +4094,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4132,14 +4132,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4440,6 +4439,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..98d228b030
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,467 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  pasring of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.sval = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE path names and column names shall be "
+						 "distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index cb9e177b5e..e06c23d0de 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 829c0f9497..7cc5020861 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1992,6 +1992,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 7811fa31e0..f0078b7874 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->sval);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index fc3617f550..f4c810c867 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -499,6 +499,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8468,7 +8470,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9715,6 +9718,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10989,16 +10995,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -11089,6 +11093,220 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format_type == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->sval)
+				);
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 7120836c70..2ffa014618 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 9ce8df17e5..9df70e6f06 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 4e81a3e859..41d05df10c 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -509,6 +511,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 27ec40dd7f..b33a9c13ba 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1564,6 +1564,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1623,6 +1636,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 90108befeb..b67c7bfaff 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,6 +73,12 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
  * TableFunc - node for a table function, such as XMLTABLE.
  *
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1243,7 +1252,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1457,6 +1467,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index ab3d8e0b52..c7365706a3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 2495c30034..e86b002392 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 98a61d7f72..1897ddffa6 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index f2f5e271b8..d89c3bef44 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..6614dd6e45 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 89249ecc97..ba0978cf7c 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1234,6 +1234,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2630,6 +2638,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.1

0003-JSON_TABLE-PLAN-DEFAULT-clause-v55.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v55.patchDownload
From a5207c0f7fc86e8be2578754da311a55253a6c7c Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 1 Feb 2022 12:17:12 -0500
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 462 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 3df418458c..663c26aba2 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19315,6 +19315,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19376,7 +19380,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19389,22 +19394,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parrent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19576,6 +19565,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19598,8 +19591,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index d6f05bd58d..022e763845 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2680,6 +2680,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2718,6 +2719,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2734,6 +2737,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 4810ea74f3..03469e51cb 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -152,6 +152,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -163,6 +165,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index acbb4ebced..e627b0bcbe 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1875,6 +1875,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1886,6 +1888,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index d82fc22cd6..267137fce2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1504,6 +1504,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1517,6 +1519,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f61ce6e0cf..87ddcb0912 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -691,6 +691,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -804,7 +809,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15682,13 +15687,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15825,6 +15832,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16703,6 +16738,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17318,6 +17354,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 98d228b030..db772995ac 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -174,12 +174,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -187,7 +188,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -195,8 +196,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -208,7 +210,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -386,6 +388,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index f0078b7874..f850392ab3 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index f4c810c867..508acbbd5f 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11283,6 +11283,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b33a9c13ba..6dd52c59c1 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1656,6 +1656,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1665,6 +1677,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index b67c7bfaff..bf2ba05af5 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1476,6 +1476,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1490,6 +1492,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c7365706a3..ac17889517 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index d89c3bef44..0cd8f73c66 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 6614dd6e45..cd97ff7f46 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index ba0978cf7c..25d94f7163 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1240,6 +1240,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.1

0004-JSON_TABLE-PLAN-clause-v55.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v55.patchDownload
From 08b7974ff0773edb735a79b89fececb596dbee74 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Tue, 1 Feb 2022 12:22:51 -0500
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 322 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1389 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 663c26aba2..58ef9f1644 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19313,9 +19313,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19339,6 +19340,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19381,7 +19392,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19566,7 +19577,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19593,18 +19604,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19683,6 +19707,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19714,9 +19755,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 022e763845..350fdf7534 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2678,9 +2678,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2698,6 +2698,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2709,6 +2710,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2718,9 +2737,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5853,6 +5872,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 03469e51cb..7b6f89907f 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -151,9 +151,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index 51faa0636c..b23e813d0a 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -866,6 +866,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index e627b0bcbe..c344ef6486 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1874,9 +1874,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 267137fce2..7a9a1d04be 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1503,9 +1503,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 87ddcb0912..9ad42fe166 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -676,6 +676,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -691,8 +703,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15694,7 +15704,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15816,12 +15826,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15833,12 +15846,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index db772995ac..f4234f4e48 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -38,12 +38,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -156,19 +159,154 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns shall contain "
+								"explicit AS pathname specification if "
+								"explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s "
+								   "was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or "
+						   "duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -186,34 +324,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -377,19 +559,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns shall contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -407,7 +650,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -415,9 +660,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -453,7 +720,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 508acbbd5f..32aac073a4 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11119,10 +11119,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11251,6 +11295,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11283,14 +11329,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 3e252067a9..1a0833ef11 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 6dd52c59c1..b23823e181 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1647,6 +1647,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1656,6 +1657,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1668,6 +1680,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1677,7 +1706,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index bf2ba05af5..a434287fe2 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1475,9 +1475,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0cd8f73c66..9467c4f67c 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' -- AS <path name> required here
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+          ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE path names and column names shall be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE path names and column names shall be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' -- without root path name
+         ^
+DETAIL:  JSON_TABLE columns shall contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index cd97ff7f46..be2d65b3ff 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns shall contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names anf path names shall be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 25d94f7163..d4a6e5f687 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1240,7 +1240,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.1

#67Himanshu Upadhyaya
upadhyaya.himanshu@gmail.com
In reply to: Andrew Dunstan (#66)
Re: SQL/JSON: JSON_TABLE

On Wed, Feb 2, 2022 at 12:44 AM Andrew Dunstan <andrew@dunslane.net> wrote:

rebased with some review comments attended to.

I am in process of reviewing these patches, initially, have started
with 0002-JSON_TABLE-v55.patch.
Tested many different scenarios with various JSON messages and these
all are working as expected. Just one question on the below output.

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON EMPTY)) jt;
a
---

(1 row)

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON ERROR)) jt;
a
---

(1 row)

is not "ERROR ON ERROR" is expected to give error?

There are a few minor comments on the patch:
1)
Few Typo
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both
parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.

Parrent should be parent.

+    <para>
+     Gerenates a column and inserts a boolean item into each row of
this column.
+    </para>
Gerenates should be Generates.
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each
row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>

Gerenates should be Generates.

+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *       pasring of JSON_TABLE

pasring should be parsing.

2) Albhabatic include.
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
include files are not in alphabetic order.
3)
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+       jsonb '[]', '$'
+       COLUMNS (
+               a int,
+               b text,
+               a jsonb
+       )
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from
one another

HINT is not much relevant, can't we simply say "JSON_TABLE column
names should be distinct from one another"?

4)
@@ -4837,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
/* Want to execute expressions inside function's memory context */
MemoryContextSwitchTo(oldcontext);

+

we can remove this empty line.

5)
/*
* The production for a qualified relation name has to exactly match the
* production for a qualified func_name, because in a FROM clause we cannot
* tell which we are parsing until we see what comes after it ('(' for a
* func_name, something else for a relation). Therefore we allow 'indirection'
* which may contain subscripts, and reject that case in the C code.
*/

I think the sentence "because in a FROM clause we cannot
* tell which we are parsing..." should be changed to "because in a
FROM clause we cannot
* tell what we are parsing "

6)
@@ -696,7 +696,7 @@ transformRangeTableFunc(ParseState *pstate,
RangeTableFunc *rtf)
char **names;
int colno;

- /* Currently only XMLTABLE is supported */

can we change(and not remove) the comment to "/* Currently only
XMLTABLE and JSON_TABLE is supported */"

7)
/*
* TableFunc - node for a table function, such as XMLTABLE.
*
* Entries in the ns_names list are either String nodes containing
* literal namespace names, or NULL pointers to represent DEFAULT.
*/
typedef struct TableFunc

can we change the comment to "...such as XMLTABLE or JSON_TABLE."?

--
Regards,
Himanshu Upadhyaya
EnterpriseDB: http://www.enterprisedb.com

#68Andrew Dunstan
andrew@dunslane.net
In reply to: Himanshu Upadhyaya (#67)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 2/9/22 08:22, Himanshu Upadhyaya wrote:

On Wed, Feb 2, 2022 at 12:44 AM Andrew Dunstan <andrew@dunslane.net> wrote:

rebased with some review comments attended to.

I am in process of reviewing these patches, initially, have started
with 0002-JSON_TABLE-v55.patch.
Tested many different scenarios with various JSON messages and these
all are working as expected. Just one question on the below output.

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON EMPTY)) jt;
a
---

(1 row)

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON ERROR)) jt;
a
---

(1 row)

is not "ERROR ON ERROR" is expected to give error?

There are a few minor comments on the patch:
1)
Few Typo
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both
parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parrent columns for all missing values.

Parrent should be parent.

+    <para>
+     Gerenates a column and inserts a boolean item into each row of
this column.
+    </para>
Gerenates should be Generates.
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     gerenates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each
row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>

Gerenates should be Generates.

+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *       pasring of JSON_TABLE

pasring should be parsing.

2) Albhabatic include.
+
+#include "postgres.h"
+
+#include "miscadmin.h"
+
include files are not in alphabetic order.
3)
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names anf path names shall be distinct)
+SELECT * FROM JSON_TABLE(
+       jsonb '[]', '$'
+       COLUMNS (
+               a int,
+               b text,
+               a jsonb
+       )
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE path names and column names shall be distinct from
one another

HINT is not much relevant, can't we simply say "JSON_TABLE column
names should be distinct from one another"?

4)
@@ -4837,6 +4844,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
/* Want to execute expressions inside function's memory context */
MemoryContextSwitchTo(oldcontext);

+

we can remove this empty line.

5)
/*
* The production for a qualified relation name has to exactly match the
* production for a qualified func_name, because in a FROM clause we cannot
* tell which we are parsing until we see what comes after it ('(' for a
* func_name, something else for a relation). Therefore we allow 'indirection'
* which may contain subscripts, and reject that case in the C code.
*/

I think the sentence "because in a FROM clause we cannot
* tell which we are parsing..." should be changed to "because in a
FROM clause we cannot
* tell what we are parsing "

6)
@@ -696,7 +696,7 @@ transformRangeTableFunc(ParseState *pstate,
RangeTableFunc *rtf)
char **names;
int colno;

- /* Currently only XMLTABLE is supported */

can we change(and not remove) the comment to "/* Currently only
XMLTABLE and JSON_TABLE is supported */"

7)
/*
* TableFunc - node for a table function, such as XMLTABLE.
*
* Entries in the ns_names list are either String nodes containing
* literal namespace names, or NULL pointers to represent DEFAULT.
*/
typedef struct TableFunc

can we change the comment to "...such as XMLTABLE or JSON_TABLE."?

This set of patches deals with items 1..7 above, but not yet the ERROR
ON ERROR issue. It also makes some message cleanups, but there is more
to come in that area.

It is based on the latest SQL/JSON Functions patch set, which does not
include the sql_json GUC patch.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-without-sql_json-GUC-v56.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-without-sql_json-GUC-v56.patchDownload
From 8bb1790c8526d21cb5aa7eb947b0816e704d94a5 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 3 Mar 2022 13:29:52 -0500
Subject: [PATCH 1/4] SQL/JSON functions (without sql_json GUC)

---
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  762 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1440 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    4 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  350 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  435 +++-
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  201 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   33 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1211 ++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  435 ++++
 54 files changed, 12710 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index df3cd5987b..e19821c4b2 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17564,6 +17564,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19719,6 +21637,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 847357bf80..25253f5377 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->sval);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d6f7d7c2d7..0483279f91 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4386,3 +4503,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format_type == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index bd86f546d7..9c8f341d96 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index d5191cf02b..b2bda86889 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index d4f8455a2b..c3242af8f2 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2298,6 +2298,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format_type);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5350,6 +5717,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index f1002afe7a..731b1419f6 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format_type);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3358,6 +3594,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3938,6 +4207,30 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index c85d8fe975..cd6c300e7b 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -818,3 +819,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format_type = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 47d0564fa2..e8de1dd3aa 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2348,6 +2456,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2678,6 +2858,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3309,6 +3490,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -4017,6 +4293,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 6bdad462c7..23750d97ab 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1751,6 +1751,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format_type, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4537,6 +4651,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3f68f7c18d..c15e81a362 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1389,6 +1389,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format_type, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2974,6 +3133,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 8dc7dd4ca2..c7b9d8d11a 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4540,7 +4540,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index a707dc9f26..eef4381477 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -382,6 +386,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		const JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -853,6 +896,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3512,6 +3567,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a03b33b53b..175e14e51d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -280,6 +280,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct GroupClause  *groupclause;
 	struct KeyActions	*keyactions;
 	struct KeyAction	*keyaction;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -555,7 +562,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -635,6 +642,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -660,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -670,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -681,12 +755,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -697,9 +771,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -712,7 +787,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -720,17 +795,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -738,7 +813,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -763,7 +838,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -781,6 +856,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -816,11 +892,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -838,6 +918,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -13052,6 +13135,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -13070,6 +13154,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13363,7 +13448,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13438,6 +13523,13 @@ interval_second:
 				}
 		;
 
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName("json");
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13894,6 +13986,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13976,6 +14108,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14228,6 +14379,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14241,6 +14401,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14528,6 +14689,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15226,6 +15389,527 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15671,6 +16355,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15711,6 +16396,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15747,10 +16433,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15767,6 +16455,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15798,7 +16487,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15841,6 +16532,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15870,6 +16562,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15899,6 +16592,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15950,6 +16644,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -16007,6 +16702,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -16074,6 +16779,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -16175,6 +16881,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16237,6 +16944,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16289,11 +16997,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16314,6 +17024,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16358,7 +17069,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16415,6 +17138,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16451,6 +17175,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16484,6 +17209,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16518,6 +17244,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16551,6 +17278,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 6c793b72ec..2e549e7b39 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 1c09ea24cd..bbd80e5c6e 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,7 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +77,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +319,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3099,3 +3161,1381 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format_type == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format_type != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format_type;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format_type == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format_type != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format_type == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format_type =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format_type = JS_FORMAT_JSONB;
+		}
+		else
+		{
+			/* Note: this includes the have_json case */
+			
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format_type = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format_type == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format_type == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format_type == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = makeNode(JsonReturning);
+	Node	   *arg;
+
+	returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+	returning->typid = JSONOID;
+	returning->typmod = -1;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	JsonReturning *returning = makeNode(JsonReturning);
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+
+	returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+	returning->typid = JSONOID;
+	returning->typmod = -1;
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 059eeb9e94..829c0f9497 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1957,6 +1957,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 50227cc098..eee0a29c08 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 2918fdbfb6..060fd7e183 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -294,6 +294,10 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup("json");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index d4c2e7b069..fb395b6f78 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1017,11 +1017,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6666,3 +6661,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 7879f342e6..492796eb83 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index f5f40a94bd..2043f2e74a 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -98,7 +77,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +101,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +142,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +240,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +250,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +286,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +609,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1116,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1169,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1180,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1201,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1229,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1267,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
 }
 
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1551,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1564,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1613,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1685,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1735,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1751,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1771,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1809,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1873,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1955,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2223,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 60442758b3..aa151a53d6 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -64,7 +64,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -689,7 +690,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -732,6 +735,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1936,7 +1942,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1946,15 +1952,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 2457061f97..2023bcd125 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2777,11 +2777,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3253,6 +3253,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5647,3 +5691,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index 9be4e305ff..ca1cfe3d36 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->sval, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index eff3734b6a..7811fa31e0 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b16526e65e..c4cac590af 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -457,6 +457,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -490,6 +496,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6245,7 +6253,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -8091,6 +8100,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8184,6 +8195,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8207,6 +8219,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8262,6 +8275,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8368,6 +8386,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format_type == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format_type == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format_type !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9527,6 +9660,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->sval);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9650,6 +9887,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9795,17 +10033,100 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (ctor->type != JSCTOR_JSON_PARSE &&
+		ctor->type != JSCTOR_JSON_SCALAR)
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9835,13 +10156,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9877,7 +10199,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9891,6 +10223,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9900,6 +10235,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9919,10 +10264,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9946,16 +10293,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9992,6 +10353,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10232,6 +10602,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index a67487e5fe..7120836c70 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(lfirst_node(String, temp)->sval);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index 2843f4b415..1934f19335 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -567,14 +567,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index bf88858171..1d8b38fdcc 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8737,6 +8737,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8744,10 +8748,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8756,6 +8776,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9628,6 +9661,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9636,10 +9673,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9648,6 +9704,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 56a89ebafb..9ce8df17e5 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 344399f6a8..538d7eca07 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 50de4c62af..872f2f0828 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 5d075f0c34..90c1451e1c 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -491,6 +501,20 @@ typedef enum NodeTag
 	T_VacuumRelation,
 	T_PublicationObjSpec,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1617702d9d..13a18e02a2 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1551,6 +1551,207 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index dab5c4ff5d..90108befeb 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1235,6 +1235,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format_type;	/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index bcef7eed2f..ab3d8e0b52 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 851e787bfd..0a22af80a2 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 8a84a0cdb4..da4a9257b3 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4cbe6edf21..bae466b523 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,22 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +419,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +434,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 865b2ff7c1..62dc3d88a4 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index cd0b5d5b61..98a61d7f72 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index dee6b8200d..5ec511fd01 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a44e07a17a..5e2b606f9b 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..1126d7caf5
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 4ce6c039b4..15e4016836 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..11f5eb2d2c
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1211 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6d8f524ae9..b8cea3a5f2 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -111,7 +111,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 2b292851e3..63fe114fed 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..98bd93c110
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,435 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.1

0002-JSON_TABLE-v56.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v56.patchDownload
From 367887e95cb5d92ed40c3ac7c0f058cef33ef182 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 3 Mar 2022 15:37:47 -0500
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  18 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  12 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 465 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 228 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  39 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2886 insertions(+), 33 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index e19821c4b2..c0e5db8a99 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18632,6 +18632,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19302,6 +19307,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Generates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Generates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     generates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index de81379da3..68622a66c8 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3793,7 +3793,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 25253f5377..c929cc2d90 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0483279f91..c4af38fd5a 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4608,6 +4608,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4700,8 +4701,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4849,6 +4856,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4860,8 +4868,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4987,6 +4997,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 0db4ed0c2f..691c3e28ce 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index c3242af8f2..81bda54042 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1393,6 +1393,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1403,7 +1404,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2665,6 +2668,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5783,6 +5856,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 731b1419f6..99856800bd 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3627,6 +3650,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index e8de1dd3aa..cbae180dba 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2454,6 +2454,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3487,6 +3489,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4444,6 +4447,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 23750d97ab..3290d28064 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1091,6 +1091,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1101,7 +1102,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1865,6 +1868,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4678,6 +4701,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c15e81a362..d82fc22cd6 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -533,6 +533,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -543,7 +544,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1494,6 +1497,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3151,6 +3178,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 175e14e51d..03e539b60a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -669,15 +669,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -691,6 +701,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -698,6 +709,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -772,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -782,8 +795,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -791,7 +804,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -893,7 +906,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -918,6 +931,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12484,6 +12501,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -13035,6 +13065,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15558,6 +15590,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15672,6 +15708,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16515,6 +16698,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16548,6 +16732,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16711,6 +16896,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -17078,6 +17264,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -17115,6 +17302,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -17158,6 +17346,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index d8b14ba7cd..dafde68b20 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,9 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	/* Currently only XMLTABLE and JSON_TABLE are supported */
+
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1102,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index bbd80e5c6e..2cea6656d9 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4093,7 +4093,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4131,14 +4131,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4439,6 +4438,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..4f581940ef
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,465 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  parsing of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.sval = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE column names must be distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index cb9e177b5e..e06c23d0de 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 829c0f9497..7cc5020861 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1992,6 +1992,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 7811fa31e0..f0078b7874 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->sval);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index c4cac590af..5db3bec79b 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -498,6 +498,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8476,7 +8478,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9723,6 +9726,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10996,16 +11002,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -11096,6 +11100,220 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format_type == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->sval)
+				);
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 7120836c70..2ffa014618 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 9ce8df17e5..9df70e6f06 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 90c1451e1c..1bcf64f9c1 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -510,6 +512,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 13a18e02a2..990964a195 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1564,6 +1564,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1623,6 +1636,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 90108befeb..ddd0c1a8e1 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,8 +73,14 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
- * TableFunc - node for a table function, such as XMLTABLE.
+ * TableFunc - node for a table function, such as XMLTABLE or JSON_TABLE.
  *
  * Entries in the ns_names list are either String nodes containing
  * literal namespace names, or NULL pointers to represent DEFAULT.
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1243,7 +1252,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1457,6 +1467,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index ab3d8e0b52..c7365706a3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 2495c30034..e86b002392 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 98a61d7f72..1897ddffa6 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 1126d7caf5..c766a441be 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names must be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE column names must be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..8b813a3c2e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names must be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index d9b83f744f..6c8412f550 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1235,6 +1235,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2633,6 +2641,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.1

0003-JSON_TABLE-PLAN-DEFAULT-clause-v56.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v56.patchDownload
From 414a053b100b11b10419d1dd00a9c78c73e5350c Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 3 Mar 2022 15:45:26 -0500
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 462 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index c0e5db8a99..52530f5987 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19315,6 +19315,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19376,7 +19380,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19389,22 +19394,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19576,6 +19565,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19598,8 +19591,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 81bda54042..e6db57712f 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2680,6 +2680,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2718,6 +2719,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2734,6 +2737,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 99856800bd..1c4a475f59 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -152,6 +152,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -163,6 +165,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 3290d28064..a17ea2e8f9 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1875,6 +1875,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1886,6 +1888,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index d82fc22cd6..267137fce2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1504,6 +1504,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1517,6 +1519,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 03e539b60a..f538752929 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -691,6 +691,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -804,7 +809,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15712,13 +15717,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15855,6 +15862,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16733,6 +16768,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17348,6 +17384,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 4f581940ef..7aaa71b49d 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -172,12 +172,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -185,7 +186,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -193,8 +194,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -206,7 +208,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -384,6 +386,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index f0078b7874..f850392ab3 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 5db3bec79b..511547993d 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11290,6 +11290,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 990964a195..fea324cd53 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1656,6 +1656,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1665,6 +1677,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index ddd0c1a8e1..8c908392f6 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1476,6 +1476,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1490,6 +1492,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c7365706a3..ac17889517 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index c766a441be..0d8c5d6add 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 8b813a3c2e..9ad1047485 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 6c8412f550..6856eec8d0 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1241,6 +1241,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.1

0004-JSON_TABLE-PLAN-clause-v56.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v56.patchDownload
From 3f31db932aa91f3ee68feb5f6e036f6967fb3d33 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Fri, 4 Mar 2022 09:54:16 -0500
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 318 ++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1385 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 52530f5987..4d82274d6f 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19313,9 +19313,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19339,6 +19340,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19381,7 +19392,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19566,7 +19577,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19593,18 +19604,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19683,6 +19707,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19714,9 +19755,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index e6db57712f..e9c4e8db87 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2678,9 +2678,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2698,6 +2698,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2709,6 +2710,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2718,9 +2737,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5866,6 +5885,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 1c4a475f59..10a4c2eb17 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -151,9 +151,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index cd6c300e7b..41e26a0fe6 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -867,6 +867,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index a17ea2e8f9..15efad4bfc 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1874,9 +1874,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 267137fce2..7a9a1d04be 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1503,9 +1503,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f538752929..f5ce0896d3 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -676,6 +676,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -691,8 +703,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15724,7 +15734,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15846,12 +15856,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15863,12 +15876,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 7aaa71b49d..ab387d4e3d 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -37,12 +37,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -154,19 +157,150 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns must contain an explicit AS pathname specification if an explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -184,34 +318,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -375,19 +553,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns must contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -405,7 +644,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -413,9 +654,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -451,7 +714,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 511547993d..aa99bba587 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11126,10 +11126,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11258,6 +11302,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11290,14 +11336,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 872f2f0828..c717468eb3 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index fea324cd53..05654519f7 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1647,6 +1647,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1656,6 +1657,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1668,6 +1680,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1677,7 +1706,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 8c908392f6..871671c6ce 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1475,9 +1475,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0d8c5d6add..2db7023206 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns must contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' -- AS <path name> required here
+         ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+          ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names must be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE column names must be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE column names must be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' -- without root path name
+         ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 9ad1047485..930d86c90e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns must contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names must be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 6856eec8d0..3c503db71a 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1241,7 +1241,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.1

#69Erikjan Rijkers
er@xs4all.nl
In reply to: Andrew Dunstan (#68)
Re: SQL/JSON: JSON_TABLE

Op 04-03-2022 om 17:33 schreef Andrew Dunstan:

This set of patches deals with items 1..7 above, but not yet the ERROR
ON ERROR issue. It also makes some message cleanups, but there is more
to come in that area.

It is based on the latest SQL/JSON Functions patch set, which does not
include the sql_json GUC patch.

[0001-SQL-JSON-functions-without-sql_json-GUC-v56.patch]
[0002-JSON_TABLE-v56.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v56.patch]
[0004-JSON_TABLE-PLAN-clause-v56.patch]

Hi,

I quickly tried the tests I already had and there are two statements
that stopped working:

testdb=# SELECT JSON('{"a": 123, "b": [true, "foo"], "a2": "bar"}'
RETURNING jsonb);
ERROR: syntax error at or near "RETURNING"
LINE 1: ...SON('{"a": 123, "b": [true, "foo"], "a2": "bar"}' RETURNING ...

testdb=# select JSON_SCALAR(123.45 returning jsonb);
ERROR: syntax error at or near "returning"
LINE 1: select JSON_SCALAR(123.45 returning jsonb)

(the '^' pointer in both cases underneath 'RETURNING'

thanks,

Erik Rijkers

Show quoted text

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#70Andrew Dunstan
andrew@dunslane.net
In reply to: Erikjan Rijkers (#69)
Re: SQL/JSON: JSON_TABLE

On 3/4/22 13:13, Erikjan Rijkers wrote:

Op 04-03-2022 om 17:33 schreef Andrew Dunstan:

This set of patches deals with items 1..7 above, but not yet the ERROR
ON ERROR issue. It also makes some message cleanups, but there is more
to come in that area.

It is based on the latest SQL/JSON Functions patch set, which does not
include the sql_json GUC patch.

[0001-SQL-JSON-functions-without-sql_json-GUC-v56.patch]
[0002-JSON_TABLE-v56.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v56.patch]
[0004-JSON_TABLE-PLAN-clause-v56.patch]

Hi,

I quickly tried the tests I already had and there are two statements
that stopped working:

testdb=# SELECT JSON('{"a": 123, "b": [true, "foo"], "a2": "bar"}'
RETURNING jsonb);
ERROR:  syntax error at or near "RETURNING"
LINE 1: ...SON('{"a": 123, "b": [true, "foo"], "a2": "bar"}' RETURNING
...

testdb=# select JSON_SCALAR(123.45 returning jsonb);
ERROR:  syntax error at or near "returning"
LINE 1: select JSON_SCALAR(123.45 returning jsonb)

  (the '^' pointer in both cases underneath 'RETURNING'

Yes, you're right, that was implemented as part of the GUC patch. I'll
try to split that out and send new patchsets with the RETURNING clause
but without the GUC (see upthread for reasons)

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#71Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#70)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 3/4/22 15:05, Andrew Dunstan wrote:

On 3/4/22 13:13, Erikjan Rijkers wrote:

Op 04-03-2022 om 17:33 schreef Andrew Dunstan:

This set of patches deals with items 1..7 above, but not yet the ERROR
ON ERROR issue. It also makes some message cleanups, but there is more
to come in that area.

It is based on the latest SQL/JSON Functions patch set, which does not
include the sql_json GUC patch.

[0001-SQL-JSON-functions-without-sql_json-GUC-v56.patch]
[0002-JSON_TABLE-v56.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v56.patch]
[0004-JSON_TABLE-PLAN-clause-v56.patch]

Hi,

I quickly tried the tests I already had and there are two statements
that stopped working:

testdb=# SELECT JSON('{"a": 123, "b": [true, "foo"], "a2": "bar"}'
RETURNING jsonb);
ERROR:  syntax error at or near "RETURNING"
LINE 1: ...SON('{"a": 123, "b": [true, "foo"], "a2": "bar"}' RETURNING
...

testdb=# select JSON_SCALAR(123.45 returning jsonb);
ERROR:  syntax error at or near "returning"
LINE 1: select JSON_SCALAR(123.45 returning jsonb)

  (the '^' pointer in both cases underneath 'RETURNING'

Yes, you're right, that was implemented as part of the GUC patch. I'll
try to split that out and send new patchsets with the RETURNING clause
but without the GUC (see upthread for reasons)

Here's a patchset with RETURNING for JSON() and JSON_SCALAR() but
without the GUC

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-without-sql_json-GUC-v57.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-without-sql_json-GUC-v57.patchDownload
From ffb9d6795953d0a17cc28b8e12d0090b8ce5f44e Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 08:56:37 -0500
Subject: [PATCH 1/4] SQL/JSON functions (without sql_json GUC)

---
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  433 ++++
 src/backend/nodes/equalfuncs.c                |  293 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  427 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  765 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1466 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    4 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  350 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  436 +++-
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   24 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   33 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1268 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  445 ++++
 54 files changed, 12809 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index df3cd5987b..e19821c4b2 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17564,6 +17564,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19719,6 +21637,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 847357bf80..25253f5377 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->sval);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d6f7d7c2d7..0483279f91 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4386,3 +4503,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format_type == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index bd86f546d7..9c8f341d96 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index d5191cf02b..b2bda86889 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index d4f8455a2b..c3242af8f2 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2298,6 +2298,373 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format_type);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5350,6 +5717,72 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index f1002afe7a..731b1419f6 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,242 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format_type);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3358,6 +3594,39 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3938,6 +4207,30 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index c85d8fe975..cd6c300e7b 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -818,3 +819,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format_type = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 47d0564fa2..e8de1dd3aa 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -956,6 +983,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1168,6 +1226,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1614,6 +1704,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2348,6 +2456,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2678,6 +2858,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3309,6 +3490,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -4017,6 +4293,157 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 6bdad462c7..23750d97ab 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1751,6 +1751,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format_type, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4537,6 +4651,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3f68f7c18d..c15e81a362 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1389,6 +1389,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format_type, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2974,6 +3133,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 8dc7dd4ca2..c7b9d8d11a 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4540,7 +4540,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index a707dc9f26..eef4381477 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -382,6 +386,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		const JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -853,6 +896,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3512,6 +3567,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a03b33b53b..70f541ece0 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -280,6 +280,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct GroupClause  *groupclause;
 	struct KeyActions	*keyactions;
 	struct KeyAction	*keyaction;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -555,7 +562,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -635,6 +642,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -660,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -670,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -681,12 +755,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -697,9 +771,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -712,7 +787,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -720,17 +795,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -738,7 +813,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -763,7 +838,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -781,6 +856,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -816,11 +892,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -838,6 +918,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -13052,6 +13135,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -13070,6 +13154,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13363,7 +13448,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13438,6 +13523,13 @@ interval_second:
 				}
 		;
 
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName("json");
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13894,6 +13986,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13976,6 +14108,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14228,6 +14379,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14241,6 +14401,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14528,6 +14689,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15226,6 +15389,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15671,6 +16358,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15711,6 +16399,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15747,10 +16436,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15767,6 +16458,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15798,7 +16490,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15841,6 +16535,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15870,6 +16565,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15899,6 +16595,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15950,6 +16647,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -16007,6 +16705,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -16074,6 +16782,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -16175,6 +16884,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16237,6 +16947,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16289,11 +17000,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16314,6 +17027,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16358,7 +17072,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16415,6 +17141,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16451,6 +17178,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16484,6 +17212,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16518,6 +17247,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16551,6 +17281,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 6c793b72ec..2e549e7b39 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 1c09ea24cd..18622fd013 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,7 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +77,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +319,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3099,3 +3161,1407 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format_type == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format_type != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format_type;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format_type == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format_type != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format_type == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format_type =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format_type = JS_FORMAT_JSONB;
+		}
+		else
+		{
+			/* Note: this includes the have_json case */
+			
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format_type = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format_type == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format_type == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format_type == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = JSONOID;
+		JsonFormatType format = JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 059eeb9e94..829c0f9497 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1957,6 +1957,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 50227cc098..eee0a29c08 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 2918fdbfb6..060fd7e183 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -294,6 +294,10 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup("json");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index d4c2e7b069..fb395b6f78 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1017,11 +1017,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6666,3 +6661,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 7879f342e6..492796eb83 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index f5f40a94bd..2043f2e74a 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -98,7 +77,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +101,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +142,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +240,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +250,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +286,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +609,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1116,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1169,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1180,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1201,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1229,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1267,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
 }
 
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1551,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1564,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1613,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1685,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1735,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1751,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1771,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1809,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1873,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1955,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2223,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 60442758b3..aa151a53d6 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -64,7 +64,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -689,7 +690,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -732,6 +735,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1936,7 +1942,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1946,15 +1952,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 2457061f97..2023bcd125 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2777,11 +2777,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3253,6 +3253,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5647,3 +5691,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index 9be4e305ff..ca1cfe3d36 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->sval, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index eff3734b6a..7811fa31e0 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b16526e65e..bc5b545fd1 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -457,6 +457,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -490,6 +496,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6245,7 +6253,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -8091,6 +8100,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_Aggref:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8184,6 +8195,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8207,6 +8219,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_Aggref:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8262,6 +8275,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8368,6 +8386,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format_type == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format_type == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format_type !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9527,6 +9660,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->sval);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9650,6 +9887,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9795,17 +10033,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == JSONOID))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9835,13 +10157,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9877,7 +10200,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9891,6 +10224,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9900,6 +10236,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9919,10 +10265,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9946,16 +10294,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9992,6 +10354,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10232,6 +10603,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index a67487e5fe..7120836c70 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(lfirst_node(String, temp)->sval);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index 2843f4b415..1934f19335 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -567,14 +567,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index bf88858171..1d8b38fdcc 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8737,6 +8737,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8744,10 +8748,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8756,6 +8776,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9628,6 +9661,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9636,10 +9673,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9648,6 +9704,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 56a89ebafb..9ce8df17e5 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 344399f6a8..538d7eca07 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -263,6 +263,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 50de4c62af..872f2f0828 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 5d075f0c34..90c1451e1c 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -491,6 +501,20 @@ typedef enum NodeTag
 	T_VacuumRelation,
 	T_PublicationObjSpec,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonExistsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1617702d9d..cf19a225db 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1551,6 +1551,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index dab5c4ff5d..90108befeb 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1235,6 +1235,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format_type;	/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index bcef7eed2f..ab3d8e0b52 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 851e787bfd..0a22af80a2 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 8a84a0cdb4..da4a9257b3 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4cbe6edf21..bae466b523 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,22 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +419,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +434,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 865b2ff7c1..62dc3d88a4 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index cd0b5d5b61..98a61d7f72 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index dee6b8200d..5ec511fd01 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a44e07a17a..5e2b606f9b 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..1126d7caf5
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 4ce6c039b4..15e4016836 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..6cadd87868
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1268 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6d8f524ae9..b8cea3a5f2 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -111,7 +111,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 2b292851e3..63fe114fed 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..51fc659b58
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,445 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.1

0002-JSON_TABLE-v57.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v57.patchDownload
From 4f4f52ec752518243c4ac2791ff93ddec70fb257 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:01:20 -0500
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  18 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  29 +
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  12 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 465 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 228 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   5 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  39 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2886 insertions(+), 33 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index e19821c4b2..c0e5db8a99 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18632,6 +18632,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19302,6 +19307,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Generates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Generates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     generates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index de81379da3..68622a66c8 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3793,7 +3793,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 25253f5377..c929cc2d90 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0483279f91..c4af38fd5a 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4608,6 +4608,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4700,8 +4701,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4849,6 +4856,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4860,8 +4868,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4987,6 +4997,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 0db4ed0c2f..691c3e28ce 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index c3242af8f2..81bda54042 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1393,6 +1393,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1403,7 +1404,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2665,6 +2668,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParentNode
+ */
+static JsonTableParentNode *
+_copyJsonTableParentNode(const JsonTableParentNode *from)
+{
+	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSiblingNode
+ */
+static JsonTableSiblingNode *
+_copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
+{
+	JsonTableSiblingNode *newnode = makeNode(JsonTableSiblingNode);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5783,6 +5856,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParentNode:
+			retval = _copyJsonTableParentNode(from);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _copyJsonTableSiblingNode(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 731b1419f6..99856800bd 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,35 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSiblingNode *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3627,6 +3650,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParentNode:
+			retval = _equalJsonTableParentNode(a, b);
+			break;
+		case T_JsonTableSiblingNode:
+			retval = _equalJsonTableSiblingNode(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index e8de1dd3aa..cbae180dba 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2454,6 +2454,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3487,6 +3489,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4444,6 +4447,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 23750d97ab..3290d28064 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1091,6 +1091,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1101,7 +1102,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1865,6 +1868,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4678,6 +4701,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParentNode:
+				_outJsonTableParentNode(str, obj);
+				break;
+			case T_JsonTableSiblingNode:
+				_outJsonTableSiblingNode(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c15e81a362..d82fc22cd6 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -533,6 +533,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -543,7 +544,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1494,6 +1497,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParentNode *
+_readJsonTableParentNode(void)
+{
+	READ_LOCALS(JsonTableParentNode);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSiblingNode *
+_readJsonTableSiblingNode(void)
+{
+	READ_LOCALS(JsonTableSiblingNode);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3151,6 +3178,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParentNode();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSiblingNode();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 70f541ece0..702c802e69 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -669,15 +669,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -691,6 +701,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -698,6 +709,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -772,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -782,8 +795,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -791,7 +804,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -893,7 +906,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -918,6 +931,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12484,6 +12501,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -13035,6 +13065,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15561,6 +15593,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15675,6 +15711,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16518,6 +16701,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16551,6 +16735,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16714,6 +16899,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -17081,6 +17267,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -17118,6 +17305,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -17161,6 +17349,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index d8b14ba7cd..dafde68b20 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,9 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	/* Currently only XMLTABLE and JSON_TABLE are supported */
+
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1102,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 18622fd013..4a5be4cdb6 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4093,7 +4093,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4131,14 +4131,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4439,6 +4438,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..4f581940ef
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,465 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  parsing of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.sval = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE column names must be distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParentNode *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblingNodes.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParentNode *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParentNode *node = makeNode(JsonTableParentNode);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParentNode *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParentNode *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index cb9e177b5e..e06c23d0de 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 829c0f9497..7cc5020861 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1992,6 +1992,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 7811fa31e0..f0078b7874 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParentNode *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParentNode *node = castNode(JsonTableParentNode, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->sval);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index bc5b545fd1..463568bbfd 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -498,6 +498,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8476,7 +8478,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9723,6 +9726,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -10997,16 +11003,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -11097,6 +11101,220 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParentNode *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format_type == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParentNode *root = castNode(JsonTableParentNode, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->sval)
+				);
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 7120836c70..2ffa014618 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 9ce8df17e5..9df70e6f06 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 90c1451e1c..1bcf64f9c1 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParentNode,
+	T_JsonTableSiblingNode,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -510,6 +512,9 @@ typedef enum NodeTag
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
 	T_JsonExistsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index cf19a225db..aaaf8d8b3b 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1564,6 +1564,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1623,6 +1636,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 90108befeb..ddd0c1a8e1 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,8 +73,14 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
- * TableFunc - node for a table function, such as XMLTABLE.
+ * TableFunc - node for a table function, such as XMLTABLE or JSON_TABLE.
  *
  * Entries in the ns_names list are either String nodes containing
  * literal namespace names, or NULL pointers to represent DEFAULT.
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1243,7 +1252,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1457,6 +1467,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParentNode -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParentNode
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParentNode;
+
+/*
+ * JsonTableSiblingNode -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSiblingNode
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSiblingNode;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index ab3d8e0b52..c7365706a3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 2495c30034..e86b002392 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 98a61d7f72..1897ddffa6 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 1126d7caf5..c766a441be 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names must be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE column names must be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..8b813a3c2e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names must be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index d9b83f744f..6c8412f550 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1235,6 +1235,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParentNode
+JsonTableScanState
+JsonTableSiblingNode
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2633,6 +2641,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.1

0003-JSON_TABLE-PLAN-DEFAULT-clause-v57.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v57.patchDownload
From 7a946cf2cfa49da5ecb9f0b037c68d7a660cb202 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:02:22 -0500
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 462 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index c0e5db8a99..52530f5987 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19315,6 +19315,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19376,7 +19380,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19389,22 +19394,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19576,6 +19565,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19598,8 +19591,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 81bda54042..e6db57712f 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2680,6 +2680,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2718,6 +2719,8 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2734,6 +2737,7 @@ _copyJsonTableSiblingNode(const JsonTableSiblingNode *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 99856800bd..1c4a475f59 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -152,6 +152,8 @@ _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNod
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -163,6 +165,7 @@ _equalJsonTableSiblingNode(const JsonTableSiblingNode *a, const JsonTableSibling
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 3290d28064..a17ea2e8f9 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1875,6 +1875,8 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1886,6 +1888,7 @@ _outJsonTableSiblingNode(StringInfo str, const JsonTableSiblingNode *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index d82fc22cd6..267137fce2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1504,6 +1504,8 @@ _readJsonTableParentNode(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1517,6 +1519,7 @@ _readJsonTableSiblingNode(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 702c802e69..f23c903430 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -691,6 +691,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -804,7 +809,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15715,13 +15720,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15858,6 +15865,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16736,6 +16771,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17351,6 +17387,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 4f581940ef..7aaa71b49d 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -172,12 +172,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSiblingNode *join = makeNode(JsonTableSiblingNode);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -185,7 +186,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblingNodes.
  */
 static Node *
@@ -193,8 +194,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -206,7 +208,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -384,6 +386,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index f0078b7874..f850392ab3 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSiblingNode *join = castNode(JsonTableSiblingNode, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 463568bbfd..282292f0f8 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11291,6 +11291,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index aaaf8d8b3b..57f94c556e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1656,6 +1656,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1665,6 +1677,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index ddd0c1a8e1..8c908392f6 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1476,6 +1476,8 @@ typedef struct JsonTableParentNode
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1490,6 +1492,7 @@ typedef struct JsonTableSiblingNode
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSiblingNode;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c7365706a3..ac17889517 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index c766a441be..0d8c5d6add 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 8b813a3c2e..9ad1047485 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 6c8412f550..6856eec8d0 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1241,6 +1241,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.1

0004-JSON_TABLE-PLAN-clause-v57.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v57.patchDownload
From 59d1087fe055c09bb8576377b4e9e0abda0edb2d Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:03:20 -0500
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 318 ++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 15 files changed, 1385 insertions(+), 137 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 52530f5987..4d82274d6f 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19313,9 +19313,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19339,6 +19340,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19381,7 +19392,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19566,7 +19577,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19593,18 +19604,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19683,6 +19707,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19714,9 +19755,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index e6db57712f..e9c4e8db87 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2678,9 +2678,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2698,6 +2698,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2709,6 +2710,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParentNode
  */
@@ -2718,9 +2737,9 @@ _copyJsonTableParentNode(const JsonTableParentNode *from)
 	JsonTableParentNode *newnode = makeNode(JsonTableParentNode);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5866,6 +5885,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParentNode:
 			retval = _copyJsonTableParentNode(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 1c4a475f59..10a4c2eb17 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -151,9 +151,9 @@ static bool
 _equalJsonTableParentNode(const JsonTableParentNode *a, const JsonTableParentNode *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index cd6c300e7b..41e26a0fe6 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -867,6 +867,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index a17ea2e8f9..15efad4bfc 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1874,9 +1874,9 @@ _outJsonTableParentNode(StringInfo str, const JsonTableParentNode *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 267137fce2..7a9a1d04be 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1503,9 +1503,9 @@ _readJsonTableParentNode(void)
 	READ_LOCALS(JsonTableParentNode);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f23c903430..b6c2754d8f 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -676,6 +676,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -691,8 +703,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15727,7 +15737,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15849,12 +15859,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15866,12 +15879,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 7aaa71b49d..ab387d4e3d 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -37,12 +37,15 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParentNode * transformJsonTableColumns(JsonTableContext *cxt,
+													   JsonTablePlan *plan,
 													   List *columns,
 													   char *pathSpec,
+													   char **pathName,
 													   int location);
 
 static Node *
@@ -154,19 +157,150 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns must contain an explicit AS pathname specification if an explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParentNode *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -184,34 +318,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblingNodes.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParentNode by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSiblingNode.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -375,19 +553,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParentNode *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParentNode *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns must contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -405,7 +644,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -413,9 +654,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -451,7 +714,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 282292f0f8..6f0e7c023a 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11127,10 +11127,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSiblingNode))
+	{
+		JsonTableSiblingNode *n = (JsonTableSiblingNode *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSiblingNode) ||
+							castNode(JsonTableParentNode, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParentNode *n = castNode(JsonTableParentNode, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSiblingNode));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11259,6 +11303,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11291,14 +11337,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 872f2f0828..c717468eb3 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 57f94c556e..609476b012 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1647,6 +1647,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1656,6 +1657,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1668,6 +1680,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1677,7 +1706,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 8c908392f6..871671c6ce 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1475,9 +1475,9 @@ typedef struct JsonTableParentNode
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0d8c5d6add..2db7023206 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns must contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' -- AS <path name> required here
+         ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+          ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names must be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE column names must be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE column names must be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' -- without root path name
+         ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 9ad1047485..930d86c90e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns must contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names must be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 6856eec8d0..3c503db71a 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1241,7 +1241,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParentNode
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSiblingNode
 JsonTokenType
-- 
2.25.1

#72Andrew Dunstan
andrew@dunslane.net
In reply to: Himanshu Upadhyaya (#67)
Re: SQL/JSON: JSON_TABLE

On 2/9/22 08:22, Himanshu Upadhyaya wrote:

On Wed, Feb 2, 2022 at 12:44 AM Andrew Dunstan <andrew@dunslane.net> wrote:

rebased with some review comments attended to.

I am in process of reviewing these patches, initially, have started
with 0002-JSON_TABLE-v55.patch.
Tested many different scenarios with various JSON messages and these
all are working as expected. Just one question on the below output.

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON EMPTY)) jt;
a
---

(1 row)

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON ERROR)) jt;
a
---

(1 row)

is not "ERROR ON ERROR" is expected to give error?

I think I understand what's going on here. In the first example 'ERROR
ON EMPTY' causes an error condition, but as the default action for an
error condition is to return null that's what happens. To get an error
raised you would need to say 'ERROR ON EMPTY ERROR ON ERROR'. I don't
know if that's according to spec. It seems kinda screwy, arguably a POLA
violation, although that would hardly be a first for the SQL Standards
body.  But I'm speculating here, I'm not a standards lawyer.

In the second case it looks like there isn't really an error. There
would be if you used 'strict' in the path expression.

This whole area needs more documentation.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#73Matthias Kurz
m.kurz@irregular.at
In reply to: Andrew Dunstan (#72)
Re: SQL/JSON: JSON_TABLE

Hi everyone!

I am watching this thread since quite a while and I am waiting eagerly a
long time already that this feature finally lands in PostgreSQL.
Given that in around 2 weeks PostgreSQL 15 will go into feature freeze (in
the last years that usually happened around the 8th of April AFAIK), is
there any chance this will be committed? As far as I understand the patches
are almost ready.

Sorry for the noise, I just wanted to draw attention that there are people
out there looking forward to JSON_TABLE ;)

Thanks everyone for your fantastic work!
Matthias

On Sun, 13 Mar 2022 at 22:22, Andrew Dunstan <andrew@dunslane.net> wrote:

Show quoted text

On 2/9/22 08:22, Himanshu Upadhyaya wrote:

On Wed, Feb 2, 2022 at 12:44 AM Andrew Dunstan <andrew@dunslane.net>

wrote:

rebased with some review comments attended to.

I am in process of reviewing these patches, initially, have started
with 0002-JSON_TABLE-v55.patch.
Tested many different scenarios with various JSON messages and these
all are working as expected. Just one question on the below output.

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON EMPTY)) jt;
a
---

(1 row)

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON ERROR)) jt;
a
---

(1 row)

is not "ERROR ON ERROR" is expected to give error?

I think I understand what's going on here. In the first example 'ERROR
ON EMPTY' causes an error condition, but as the default action for an
error condition is to return null that's what happens. To get an error
raised you would need to say 'ERROR ON EMPTY ERROR ON ERROR'. I don't
know if that's according to spec. It seems kinda screwy, arguably a POLA
violation, although that would hardly be a first for the SQL Standards
body. But I'm speculating here, I'm not a standards lawyer.

In the second case it looks like there isn't really an error. There
would be if you used 'strict' in the path expression.

This whole area needs more documentation.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#74Oleg Bartunov
obartunov@postgrespro.ru
In reply to: Matthias Kurz (#73)
Re: SQL/JSON: JSON_TABLE

On Tue, Mar 22, 2022 at 12:53 PM Matthias Kurz <m.kurz@irregular.at> wrote:

Hi everyone!

I am watching this thread since quite a while and I am waiting eagerly a
long time already that this feature finally lands in PostgreSQL.
Given that in around 2 weeks PostgreSQL 15 will go into feature freeze (in
the last years that usually happened around the 8th of April AFAIK), is
there any chance this will be committed? As far as I understand the patches
are almost ready.

We are waiting too :)

Sorry for the noise, I just wanted to draw attention that there are people
out there looking forward to JSON_TABLE ;)

IS JSON is also cool in light of the work on JSON Schema
https://github.com/json-schema-org/vocab-database/blob/main/database.md,
which opens a lot of useful features and optimizations like json
dictionary compression.

Thanks everyone for your fantastic work!
Matthias

On Sun, 13 Mar 2022 at 22:22, Andrew Dunstan <andrew@dunslane.net> wrote:

On 2/9/22 08:22, Himanshu Upadhyaya wrote:

On Wed, Feb 2, 2022 at 12:44 AM Andrew Dunstan <andrew@dunslane.net>

wrote:

rebased with some review comments attended to.

I am in process of reviewing these patches, initially, have started
with 0002-JSON_TABLE-v55.patch.
Tested many different scenarios with various JSON messages and these
all are working as expected. Just one question on the below output.

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON EMPTY)) jt;
a
---

(1 row)

‘postgres[1406146]=#’SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS
(a int PATH '$.a' ERROR ON ERROR)) jt;
a
---

(1 row)

is not "ERROR ON ERROR" is expected to give error?

I think I understand what's going on here. In the first example 'ERROR
ON EMPTY' causes an error condition, but as the default action for an
error condition is to return null that's what happens. To get an error
raised you would need to say 'ERROR ON EMPTY ERROR ON ERROR'. I don't
know if that's according to spec. It seems kinda screwy, arguably a POLA
violation, although that would hardly be a first for the SQL Standards
body. But I'm speculating here, I'm not a standards lawyer.

In the second case it looks like there isn't really an error. There
would be if you used 'strict' in the path expression.

This whole area needs more documentation.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

--
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#75Andrew Dunstan
andrew@dunslane.net
In reply to: Oleg Bartunov (#74)
Re: SQL/JSON: JSON_TABLE

On 3/22/22 09:28, Oleg Bartunov wrote:

On Tue, Mar 22, 2022 at 12:53 PM Matthias Kurz <m.kurz@irregular.at>
wrote:

Hi everyone!

I am watching this thread since quite a while and I am waiting
eagerly a long time already that this feature finally lands in
PostgreSQL.
Given that in around 2 weeks PostgreSQL 15 will go into feature
freeze (in the last years that usually happened around the 8th of
April AFAIK), is there any chance this will be committed? As far
as I understand the patches are almost ready.

We are waiting too :)

I'm planning on pushing the functions patch set this week and json-table
next week.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#76Matthias Kurz
m.kurz@irregular.at
In reply to: Andrew Dunstan (#75)
Re: SQL/JSON: JSON_TABLE

On Tue, 22 Mar 2022 at 15:31, Andrew Dunstan <andrew@dunslane.net> wrote:

I'm planning on pushing the functions patch set this week and json-table
next week.

Great! Thank you very much!

#77Alvaro Herrera
alvherre@alvh.no-ip.org
In reply to: Andrew Dunstan (#75)
Re: SQL/JSON: JSON_TABLE

On 2022-Mar-22, Andrew Dunstan wrote:

I'm planning on pushing the functions patch set this week and json-table
next week.

I think it'd be a good idea to push the patches one by one and let a day
between each. That would make it easier to chase buildfarm issues
individually, and make sure they are fixed before the next step.
Each patch in each series is already big enough.

--
Álvaro Herrera PostgreSQL Developer — https://www.EnterpriseDB.com/

#78Daniel Gustafsson
daniel@yesql.se
In reply to: Andrew Dunstan (#75)
Re: SQL/JSON: JSON_TABLE

On 22 Mar 2022, at 16:31, Andrew Dunstan <andrew@dunslane.net> wrote:

I'm planning on pushing the functions patch set this week and json-table
next week.

My comments from 30827B3C-EDF6-4D41-BBF1-2981818744A8@yesql.se are yet to be
addressed (or at all responded to) in this patchset. I'll paste the ones which
still apply to make it easier:

+ into both child and parrent columns for all missing values.
s/parrent/parent/

-           objectname = "xmltable";
+           objectname = rte->tablefunc ?
+               rte->tablefunc->functype == TFT_XMLTABLE ?
+               "xmltable" : "json_table" : NULL;
In which case can rte->tablefunc be NULL for a T_TableFuncScan? Also, nested
ternary operators are confusing at best, I think this should be rewritten as
plain if statements.

In general when inspecting functype I think it's better to spell it out with if
statements rather than ternary since it allows for grepping the code easier.
Having to grep for TFT_XMLTABLE to find where TFT_JSON_TABLE could be used
isn't all that convenient.

+ errmsg("JSON_TABLE() is not yet implemented for json type"),
I can see this being potentially confusing to many, en errhint with a reference
to jsonb seems like a good idea.

+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
This comment is IMO misleading since the function isn't actually recursive, but a
helper function for a recursive function.
+   switch (get_typtype(typid))
+   {
+       case TYPTYPE_COMPOSITE:
+           return true;
+
+       case TYPTYPE_DOMAIN:
+           return typeIsComposite(getBaseType(typid));
+   }
switch statements without a default runs the risk of attracting unwanted
compiler warning attention, or make static analyzers angry. This one can
easily be rewritten with two if-statements on a cached get_typtype()
returnvalue.

+ * Returned false at the end of a scan, true otherwise.
s/Returned/Returns/ (applies at two places)

+ /* state->ordinal--; */ /* skip current outer row, reset counter */
Is this dead code to be removed, or left in there as a reminder to fix
something?

--
Daniel Gustafsson https://vmware.com/

#79Oleg Bartunov
obartunov@postgrespro.ru
In reply to: Andrew Dunstan (#75)
Re: SQL/JSON: JSON_TABLE

On Tue, Mar 22, 2022 at 5:32 PM Andrew Dunstan <andrew@dunslane.net> wrote:

On 3/22/22 09:28, Oleg Bartunov wrote:

On Tue, Mar 22, 2022 at 12:53 PM Matthias Kurz <m.kurz@irregular.at>
wrote:

Hi everyone!

I am watching this thread since quite a while and I am waiting
eagerly a long time already that this feature finally lands in
PostgreSQL.
Given that in around 2 weeks PostgreSQL 15 will go into feature
freeze (in the last years that usually happened around the 8th of
April AFAIK), is there any chance this will be committed? As far
as I understand the patches are almost ready.

We are waiting too :)

I'm planning on pushing the functions patch set this week and json-table
next week.

Great, Andrew !

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

--
Postgres Professional: http://www.postgrespro.com
The Russian Postgres Company

#80Andrew Dunstan
andrew@dunslane.net
In reply to: Alvaro Herrera (#77)
Re: SQL/JSON: JSON_TABLE

On 3/22/22 10:53, Alvaro Herrera wrote:

On 2022-Mar-22, Andrew Dunstan wrote:

I'm planning on pushing the functions patch set this week and json-table
next week.

I think it'd be a good idea to push the patches one by one and let a day
between each. That would make it easier to chase buildfarm issues
individually, and make sure they are fixed before the next step.
Each patch in each series is already big enough.

OK, can do it that way. First one will be later today then.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#81Andrew Dunstan
andrew@dunslane.net
In reply to: Daniel Gustafsson (#78)
Re: SQL/JSON: JSON_TABLE

On 3/22/22 10:55, Daniel Gustafsson wrote:

On 22 Mar 2022, at 16:31, Andrew Dunstan <andrew@dunslane.net> wrote:
I'm planning on pushing the functions patch set this week and json-table
next week.

My comments from 30827B3C-EDF6-4D41-BBF1-2981818744A8@yesql.se are yet to be
addressed (or at all responded to) in this patchset. I'll paste the ones which
still apply to make it easier:

Thanks for reminding me. I will make sure these are attended to.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#82Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#80)
Re: SQL/JSON: JSON_TABLE

On 3/22/22 11:27, Andrew Dunstan wrote:

On 3/22/22 10:53, Alvaro Herrera wrote:

On 2022-Mar-22, Andrew Dunstan wrote:

I'm planning on pushing the functions patch set this week and json-table
next week.

I think it'd be a good idea to push the patches one by one and let a day
between each. That would make it easier to chase buildfarm issues
individually, and make sure they are fixed before the next step.
Each patch in each series is already big enough.

OK, can do it that way. First one will be later today then.

OK, pushed the first of the functions patches. That means the cfbot will
break on these two CF items, but it's way too much trouble to have to
remake the patch sets every day, so we can just live without the cfbot
on these for a bit. I will of course test before committing and fix any
bitrot.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#83Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#71)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 3/5/22 09:35, Andrew Dunstan wrote:

On 3/4/22 15:05, Andrew Dunstan wrote:

On 3/4/22 13:13, Erikjan Rijkers wrote:

Op 04-03-2022 om 17:33 schreef Andrew Dunstan:

This set of patches deals with items 1..7 above, but not yet the ERROR
ON ERROR issue. It also makes some message cleanups, but there is more
to come in that area.

It is based on the latest SQL/JSON Functions patch set, which does not
include the sql_json GUC patch.

[0001-SQL-JSON-functions-without-sql_json-GUC-v56.patch]
[0002-JSON_TABLE-v56.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v56.patch]
[0004-JSON_TABLE-PLAN-clause-v56.patch]

Hi,

I quickly tried the tests I already had and there are two statements
that stopped working:

testdb=# SELECT JSON('{"a": 123, "b": [true, "foo"], "a2": "bar"}'
RETURNING jsonb);
ERROR:  syntax error at or near "RETURNING"
LINE 1: ...SON('{"a": 123, "b": [true, "foo"], "a2": "bar"}' RETURNING
...

testdb=# select JSON_SCALAR(123.45 returning jsonb);
ERROR:  syntax error at or near "returning"
LINE 1: select JSON_SCALAR(123.45 returning jsonb)

  (the '^' pointer in both cases underneath 'RETURNING'

Yes, you're right, that was implemented as part of the GUC patch. I'll
try to split that out and send new patchsets with the RETURNING clause
but without the GUC (see upthread for reasons)

Here's a patchset with RETURNING for JSON() and JSON_SCALAR() but
without the GUC

Here's a new set with the latest sql/json functions patch and fixes for
some further node handling  inadequacies.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-without-sql_json-GUC-v58.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-without-sql_json-GUC-v58.patchDownload
From 7878098d45da14f0d52e3e65ed0df2a25a9862fc Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 24 Mar 2022 15:33:32 -0400
Subject: [PATCH 1/4] SQL/JSON functions (without sql_json GUC)

---
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  453 ++++
 src/backend/nodes/equalfuncs.c                |  353 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  458 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  765 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1466 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    4 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  350 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  436 +++-
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   23 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   33 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1268 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  445 ++++
 54 files changed, 12919 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 8a802fb225..891d237de1 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17564,6 +17564,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19719,6 +21637,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index e0656bfe85..d4d3850ec7 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->sval);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 64bd17b62e..9f626761b1 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4380,3 +4497,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format_type == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returned a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index bd86f546d7..9c8f341d96 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index d5191cf02b..b2bda86889 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index d4f8455a2b..31b488733a 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2298,6 +2298,390 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format_type);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonParseExpr
+ */
+static JsonParseExpr *
+_copyJsonParseExpr(const JsonParseExpr *from)
+{
+	JsonParseExpr  *newnode = makeNode(JsonParseExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5350,6 +5734,75 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonParseExpr:
+			retval = _copyJsonParseExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index f1002afe7a..e6cb748a18 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,290 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format_type);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonParseExpr(const JsonParseExpr *a, const JsonParseExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonFuncExpr(const JsonFuncExpr *a, const JsonFuncExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(common);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonCommon(const JsonCommon *a, const JsonCommon *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(pathspec);
+	COMPARE_STRING_FIELD(pathname);
+	COMPARE_NODE_FIELD(passing);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArgument(const JsonArgument *a, const JsonArgument *b)
+{
+	COMPARE_NODE_FIELD(val);
+	COMPARE_STRING_FIELD(name);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3358,6 +3642,42 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonParseExpr:
+			retval = _equalJsonParseExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3938,6 +4258,39 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
+		case T_JsonFuncExpr:
+			retval = _equalJsonFuncExpr(a, b);
+			break;
+		case T_JsonCommon:
+			retval = _equalJsonCommon(a, b);
+			break;
+		case T_JsonArgument:
+			retval = _equalJsonArgument(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index c85d8fe975..cd6c300e7b 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -818,3 +819,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format_type = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ec25aae6e3..2fb2be2541 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -958,6 +985,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1170,6 +1228,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1616,6 +1706,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2350,6 +2458,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2680,6 +2860,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3311,6 +3492,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -3585,6 +3861,7 @@ raw_expression_tree_walker(Node *node,
 		case T_ParamRef:
 		case T_A_Const:
 		case T_A_Star:
+		case T_JsonFormat:
 			/* primitive node types with no subnodes */
 			break;
 		case T_Alias:
@@ -4019,6 +4296,187 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonParseExpr:
+			{
+				JsonParseExpr *jpe = (JsonParseExpr *) node;
+
+				if (walker(jpe->expr, context))
+					return true;
+				if (walker(jpe->output, context))
+					return true;
+			}
+			break;
+		case T_JsonScalarExpr:
+			{
+				JsonScalarExpr *jse = (JsonScalarExpr *) node;
+
+				if (walker(jse->expr, context))
+					return true;
+				if (walker(jse->output, context))
+					return true;
+			}
+			break;
+		case T_JsonSerializeExpr:
+			{
+				JsonSerializeExpr *jse = (JsonSerializeExpr *) node;
+
+				if (walker(jse->expr, context))
+					return true;
+				if (walker(jse->output, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 6bdad462c7..23750d97ab 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1751,6 +1751,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format_type, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4537,6 +4651,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3f68f7c18d..c15e81a362 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1389,6 +1389,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format_type, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2974,6 +3133,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 4d9f3b4bb6..09271694ee 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4546,7 +4546,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index 413dcac036..e381ae512a 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -382,6 +386,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		const JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -853,6 +896,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3512,6 +3567,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0036c2f9e2..796f9c5b4c 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -280,6 +280,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct GroupClause  *groupclause;
 	struct KeyActions	*keyactions;
 	struct KeyAction	*keyaction;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -555,7 +562,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -635,6 +642,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -660,7 +734,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -670,7 +744,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -681,12 +755,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -697,9 +771,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -712,7 +787,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -720,17 +795,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -738,7 +813,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -763,7 +838,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -781,6 +856,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -816,11 +892,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -838,6 +918,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -13061,6 +13144,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -13079,6 +13163,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13372,7 +13457,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13447,6 +13532,13 @@ interval_second:
 				}
 		;
 
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName("json");
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13903,6 +13995,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -13985,6 +14117,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14237,6 +14388,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14250,6 +14410,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14537,6 +14698,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15235,6 +15398,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15680,6 +16367,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15720,6 +16408,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15756,10 +16445,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15776,6 +16467,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15807,7 +16499,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15850,6 +16544,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15879,6 +16574,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15908,6 +16604,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15959,6 +16656,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -16016,6 +16714,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -16083,6 +16791,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -16184,6 +16893,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16246,6 +16956,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16298,11 +17009,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16323,6 +17036,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16367,7 +17081,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16424,6 +17150,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16460,6 +17187,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16493,6 +17221,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16527,6 +17256,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16560,6 +17290,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 6c793b72ec..2e549e7b39 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 1c09ea24cd..18622fd013 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,7 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +77,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +319,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3099,3 +3161,1407 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format_type == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format_type != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format_type;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format_type == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format_type != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format_type == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format_type =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format_type = JS_FORMAT_JSONB;
+		}
+		else
+		{
+			/* Note: this includes the have_json case */
+			
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format_type = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format_type == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format_type == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format_type == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = JSONOID;
+		JsonFormatType format = JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 059eeb9e94..829c0f9497 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1957,6 +1957,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 50227cc098..eee0a29c08 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 2918fdbfb6..060fd7e183 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -294,6 +294,10 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup("json");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index ed698f788d..ac74333be5 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1023,11 +1023,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6672,3 +6667,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 7879f342e6..492796eb83 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index f5f40a94bd..2043f2e74a 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -98,7 +77,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +101,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +142,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +240,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +250,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +286,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +609,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1116,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1169,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1180,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1201,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1229,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1267,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
 }
 
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1551,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1564,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1613,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1685,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1735,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1751,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1771,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1809,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1873,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1955,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2223,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 60442758b3..aa151a53d6 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -64,7 +64,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -689,7 +690,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -732,6 +735,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1936,7 +1942,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1946,15 +1952,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 29664aa6e4..a682d9c973 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2658,11 +2658,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3134,6 +3134,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5528,3 +5572,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index 9be4e305ff..ca1cfe3d36 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->sval, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index eff3734b6a..7811fa31e0 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 7f4f3f7369..e9b7970acc 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -457,6 +457,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -490,6 +496,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6245,7 +6253,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -8093,6 +8102,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_GroupingFunc:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8186,6 +8197,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8210,6 +8222,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_GroupingFunc:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8266,6 +8279,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8372,6 +8390,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format_type == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format_type == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format_type !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9531,6 +9664,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->sval);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9654,6 +9891,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9799,17 +10037,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == JSONOID))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9839,13 +10161,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9881,7 +10204,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9895,6 +10228,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9904,6 +10240,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9923,10 +10269,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9950,16 +10298,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9996,6 +10358,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10236,6 +10607,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index a67487e5fe..7120836c70 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(lfirst_node(String, temp)->sval);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index 2843f4b415..1934f19335 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -567,14 +567,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d8e8715ed1..1933bb8980 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8737,6 +8737,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8744,10 +8748,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8756,6 +8776,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9628,6 +9661,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9636,10 +9673,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9648,6 +9704,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 56a89ebafb..9ce8df17e5 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 82925b4b63..873772f188 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -265,6 +265,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 50de4c62af..872f2f0828 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 5d075f0c34..37deb134b9 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -491,6 +501,19 @@ typedef enum NodeTag
 	T_VacuumRelation,
 	T_PublicationObjSpec,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 2f618cb229..aecfb6456e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1553,6 +1553,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 439e4b4a9d..cc28c20c0e 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1233,6 +1233,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format_type;	/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index bcef7eed2f..ab3d8e0b52 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 851e787bfd..0a22af80a2 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 8a84a0cdb4..da4a9257b3 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4cbe6edf21..bae466b523 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,22 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +419,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +434,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 865b2ff7c1..62dc3d88a4 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index cd0b5d5b61..98a61d7f72 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index dee6b8200d..5ec511fd01 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a44e07a17a..5e2b606f9b 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..1126d7caf5
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 4ce6c039b4..15e4016836 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..6cadd87868
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1268 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6d8f524ae9..b8cea3a5f2 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -111,7 +111,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 2b292851e3..63fe114fed 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..51fc659b58
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,445 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.1

0002-JSON_TABLE-v58.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v58.patchDownload
From bb04992d19e8e3539625ed0e07823715e75418da Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:01:20 -0500
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   4 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  18 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  65 +++
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  12 +-
 src/backend/parser/parse_expr.c             |  23 +-
 src/backend/parser/parse_jsontable.c        | 465 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 228 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   4 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  39 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   5 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2921 insertions(+), 33 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 891d237de1..a256f8123f 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18632,6 +18632,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19302,6 +19307,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Generates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Generates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     generates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 9f632285b6..3b56adbb42 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3793,7 +3793,9 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			objectname = rte->tablefunc ?
+				rte->tablefunc->functype == TFT_XMLTABLE ?
+				"xmltable" : "json_table" : NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index d4d3850ec7..38b94c0276 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 9f626761b1..6a2af28aac 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4602,6 +4602,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4694,8 +4695,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4843,6 +4850,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4854,8 +4862,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4981,6 +4991,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 0db4ed0c2f..691c3e28ce 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 31b488733a..839b32d549 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1393,6 +1393,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1403,7 +1404,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2682,6 +2685,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParent
+ */
+static JsonTableParent *
+_copyJsonTableParent(const JsonTableParent *from)
+{
+	JsonTableParent *newnode = makeNode(JsonTableParent);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSibling
+ */
+static JsonTableSibling *
+_copyJsonTableSibling(const JsonTableSibling *from)
+{
+	JsonTableSibling *newnode = makeNode(JsonTableSibling);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5803,6 +5876,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParent:
+			retval = _copyJsonTableParent(from);
+			break;
+		case T_JsonTableSibling:
+			retval = _copyJsonTableSibling(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index e6cb748a18..f911da5ee9 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,65 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTable(const JsonTable *a, const JsonTable *b)
+{
+	COMPARE_NODE_FIELD(common);
+	COMPARE_NODE_FIELD(columns);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(alias);
+	COMPARE_SCALAR_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonTableColumn(const JsonTableColumn *a, const JsonTableColumn *b)
+{
+	COMPARE_SCALAR_FIELD(coltype);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_STRING_FIELD(pathspec);
+	COMPARE_SCALAR_FIELD(format);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_NODE_FIELD(columns);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_SCALAR_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonTableParent(const JsonTableParent *a, const JsonTableParent *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSibling(const JsonTableSibling *a, const JsonTableSibling *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3678,6 +3731,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParent:
+			retval = _equalJsonTableParent(a, b);
+			break;
+		case T_JsonTableSibling:
+			retval = _equalJsonTableSibling(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -4291,6 +4350,12 @@ equal(const void *a, const void *b)
 		case T_JsonArgument:
 			retval = _equalJsonArgument(a, b);
 			break;
+		case T_JsonTable:
+			retval = _equalJsonTable(a, b);
+			break;
+		case T_JsonTableColumn:
+			retval = _equalJsonTableColumn(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 2fb2be2541..efb0bac946 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2456,6 +2456,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3489,6 +3491,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4477,6 +4480,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 23750d97ab..e5a725a636 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1091,6 +1091,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1101,7 +1102,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1865,6 +1868,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParent(StringInfo str, const JsonTableParent *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSibling(StringInfo str, const JsonTableSibling *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4678,6 +4701,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParent:
+				_outJsonTableParent(str, obj);
+				break;
+			case T_JsonTableSibling:
+				_outJsonTableSibling(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c15e81a362..3b63df6edc 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -533,6 +533,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -543,7 +544,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1494,6 +1497,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParent *
+_readJsonTableParent(void)
+{
+	READ_LOCALS(JsonTableParent);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSibling *
+_readJsonTableSibling(void)
+{
+	READ_LOCALS(JsonTableSibling);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3151,6 +3178,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParent();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSibling();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 796f9c5b4c..aa56fd68fd 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -669,15 +669,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -691,6 +701,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -698,6 +709,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -772,7 +785,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -782,8 +795,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -791,7 +804,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -893,7 +906,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -918,6 +931,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12493,6 +12510,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -13044,6 +13074,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15570,6 +15602,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15684,6 +15720,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16527,6 +16710,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16560,6 +16744,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16723,6 +16908,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -17090,6 +17276,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -17127,6 +17314,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -17170,6 +17358,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index d8b14ba7cd..dafde68b20 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,9 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	/* Currently only XMLTABLE and JSON_TABLE are supported */
+
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1102,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 18622fd013..4a5be4cdb6 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4093,7 +4093,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4131,14 +4131,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4439,6 +4438,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..ba7b0f9559
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,465 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  parsing of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParent * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.sval = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Recursively register column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE column names must be distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParent *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSibling *join = makeNode(JsonTableSibling);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblings.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	switch (get_typtype(typid))
+	{
+		case TYPTYPE_COMPOSITE:
+			return true;
+
+		case TYPTYPE_DOMAIN:
+			return typeIsComposite(getBaseType(typid));
+	}
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParent *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParent *node = makeNode(JsonTableParent);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParent *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParent *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index cb9e177b5e..e06c23d0de 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 829c0f9497..7cc5020861 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1992,6 +1992,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 7811fa31e0..6b29d9c6c9 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParent *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSibling))
+	{
+		JsonTableSibling *join = castNode(JsonTableSibling, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParent *node = castNode(JsonTableParent, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParent *root = castNode(JsonTableParent, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->sval);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returned false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index e9b7970acc..43d04644e1 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -498,6 +498,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParent *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8480,7 +8482,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9727,6 +9730,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -11001,16 +11007,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -11101,6 +11105,220 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSibling))
+	{
+		JsonTableSibling *n = (JsonTableSibling *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParent *n = castNode(JsonTableParent, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParent *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format_type == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParent *root = castNode(JsonTableParent, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->sval)
+				);
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 7120836c70..2ffa014618 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 9ce8df17e5..9df70e6f06 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 37deb134b9..58b61cf3ab 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParent,
+	T_JsonTableSibling,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -509,6 +511,8 @@ typedef enum NodeTag
 	T_JsonArrayAgg,
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index aecfb6456e..74c2ab0fe4 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1566,6 +1566,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1625,6 +1638,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index cc28c20c0e..47853cd763 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,8 +73,14 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
- * TableFunc - node for a table function, such as XMLTABLE.
+ * TableFunc - node for a table function, such as XMLTABLE or JSON_TABLE.
  *
  * Entries in the ns_names list are either String nodes containing
  * literal namespace names, or NULL pointers to represent DEFAULT.
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1241,7 +1250,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1455,6 +1465,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParent -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParent
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParent;
+
+/*
+ * JsonTableSibling -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSibling
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSibling;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index ab3d8e0b52..c7365706a3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 2495c30034..e86b002392 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 98a61d7f72..1897ddffa6 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..3096a5f91c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,8 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 1126d7caf5..c766a441be 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names must be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE column names must be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..8b813a3c2e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names must be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 49688036a7..6f6b0e7f12 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1236,6 +1236,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParent
+JsonTableScanState
+JsonTableSibling
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2638,6 +2646,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.1

0003-JSON_TABLE-PLAN-DEFAULT-clause-v58.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v58.patchDownload
From cae40f80144ec88318ae6c32c00eeb11d2f0f9a1 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:02:22 -0500
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 ++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 120 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 +++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 462 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index a256f8123f..ed530a170c 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19315,6 +19315,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19376,7 +19380,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19389,22 +19394,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19576,6 +19565,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19598,8 +19591,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parrent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 839b32d549..1cc8da9662 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2697,6 +2697,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2735,6 +2736,8 @@ _copyJsonTableParent(const JsonTableParent *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2751,6 +2754,7 @@ _copyJsonTableSibling(const JsonTableSibling *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index f911da5ee9..ae1cca2677 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -182,6 +182,8 @@ _equalJsonTableParent(const JsonTableParent *a, const JsonTableParent *b)
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -193,6 +195,7 @@ _equalJsonTableSibling(const JsonTableSibling *a, const JsonTableSibling *b)
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index e5a725a636..da920f3d36 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1875,6 +1875,8 @@ _outJsonTableParent(StringInfo str, const JsonTableParent *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1886,6 +1888,7 @@ _outJsonTableSibling(StringInfo str, const JsonTableSibling *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3b63df6edc..4a9392647c 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1504,6 +1504,8 @@ _readJsonTableParent(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1517,6 +1519,7 @@ _readJsonTableSibling(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index aa56fd68fd..3ee19250a6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -691,6 +691,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -804,7 +809,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15724,13 +15729,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15867,6 +15874,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16745,6 +16780,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17360,6 +17396,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index ba7b0f9559..d254312609 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -172,12 +172,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSibling *join = makeNode(JsonTableSibling);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -185,7 +186,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblings.
  */
 static Node *
@@ -193,8 +194,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -206,7 +208,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -384,6 +386,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 6b29d9c6c9..5667d503f8 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSibling *join = castNode(JsonTableSibling, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returned false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
+	}
+
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returned false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,44 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
+
+		/* state->ordinal--; */	/* skip current outer row, reset counter */
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 43d04644e1..46a492dc95 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11295,6 +11295,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 74c2ab0fe4..1fa4c1e6bb 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1658,6 +1658,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1667,6 +1679,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 47853cd763..098f4c96ab 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1474,6 +1474,8 @@ typedef struct JsonTableParent
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1488,6 +1490,7 @@ typedef struct JsonTableSibling
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSibling;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c7365706a3..ac17889517 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index c766a441be..0d8c5d6add 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 8b813a3c2e..9ad1047485 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 6f6b0e7f12..04b9698d1f 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1242,6 +1242,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParent
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSibling
 JsonTokenType
-- 
2.25.1

0004-JSON_TABLE-PLAN-clause-v58.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v58.patchDownload
From 72cfa2f9629675cd9a19f84f7c2d66f69461ae12 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:03:20 -0500
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 324 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/nodes.h                   |   1 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 16 files changed, 1389 insertions(+), 140 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index ed530a170c..9c369e1a35 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19313,9 +19313,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19339,6 +19340,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19381,7 +19392,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19566,7 +19577,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19593,18 +19604,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19683,6 +19707,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19714,9 +19755,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 1cc8da9662..539dae74d3 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2695,9 +2695,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2715,6 +2715,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2726,6 +2727,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParent
  */
@@ -2735,9 +2754,9 @@ _copyJsonTableParent(const JsonTableParent *from)
 	JsonTableParent *newnode = makeNode(JsonTableParent);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5886,6 +5905,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParent:
 			retval = _copyJsonTableParent(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index ae1cca2677..76cd75467d 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -181,9 +181,9 @@ static bool
 _equalJsonTableParent(const JsonTableParent *a, const JsonTableParent *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index cd6c300e7b..41e26a0fe6 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -867,6 +867,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index da920f3d36..70a9aeb372 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1874,9 +1874,9 @@ _outJsonTableParent(StringInfo str, const JsonTableParent *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 4a9392647c..de1f6e0043 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1503,9 +1503,9 @@ _readJsonTableParent(void)
 	READ_LOCALS(JsonTableParent);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 3ee19250a6..8d6adb372a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -676,6 +676,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -691,8 +703,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15736,7 +15746,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15858,12 +15868,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15875,12 +15888,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index d254312609..3a5971628b 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -37,13 +37,16 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParent * transformJsonTableColumns(JsonTableContext *cxt,
-													   List *columns,
-													   char *pathSpec,
-													   int location);
+												   JsonTablePlan *plan,
+												   List *columns,
+												   char *pathSpec,
+												   char **pathName,
+												   int location);
 
 static Node *
 makeStringConst(char *str, int location)
@@ -154,19 +157,150 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns must contain an explicit AS pathname specification if an explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParent *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -184,34 +318,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblings.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParent by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSibling.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -375,19 +553,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParent *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParent *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns must contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -405,7 +644,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -413,9 +654,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -451,7 +714,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 46a492dc95..5ad9d01398 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11131,10 +11131,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSibling))
+	{
+		JsonTableSibling *n = (JsonTableSibling *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSibling) ||
+							castNode(JsonTableParent, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSibling) ||
+							castNode(JsonTableParent, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParent *n = castNode(JsonTableParent, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSibling));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11263,6 +11307,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11295,14 +11341,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 872f2f0828..c717468eb3 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 58b61cf3ab..b883b6e39f 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -513,6 +513,7 @@ typedef enum NodeTag
 	T_JsonIsPredicate,
 	T_JsonTable,
 	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1fa4c1e6bb..3926750399 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1649,6 +1649,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1658,6 +1659,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1670,6 +1682,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1679,7 +1708,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 098f4c96ab..01d0f76df3 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1473,9 +1473,9 @@ typedef struct JsonTableParent
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0d8c5d6add..2db7023206 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns must contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' -- AS <path name> required here
+         ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+          ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names must be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE column names must be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE column names must be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' -- without root path name
+         ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 9ad1047485..930d86c90e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns must contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names must be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 04b9698d1f..917ac87b0f 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1242,7 +1242,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParent
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSibling
 JsonTokenType
-- 
2.25.1

#84Andrew Dunstan
andrew@dunslane.net
In reply to: Daniel Gustafsson (#78)
4 attachment(s)
Re: SQL/JSON: JSON_TABLE

On 3/22/22 10:55, Daniel Gustafsson wrote:

On 22 Mar 2022, at 16:31, Andrew Dunstan <andrew@dunslane.net> wrote:
I'm planning on pushing the functions patch set this week and json-table
next week.

My comments from 30827B3C-EDF6-4D41-BBF1-2981818744A8@yesql.se are yet to be
addressed (or at all responded to) in this patchset. I'll paste the ones which
still apply to make it easier:

I think I have fixed all those. See attached. I haven't prepared a new
patch set for SQL/JSON functions because there's just one typo to fix,
but I won't forget it. Please let me know if there's anything else you see.

At this stage I think I have finished with the actual code, and I'm
concentrating on improving the docs a bit.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Attachments:

0001-SQL-JSON-functions-without-sql_json-GUC-v59.patchtext/x-patch; charset=UTF-8; name=0001-SQL-JSON-functions-without-sql_json-GUC-v59.patchDownload
From 0cbd4f65749e41886efe4971fffcca4e8f62d882 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Thu, 24 Mar 2022 15:33:32 -0400
Subject: [PATCH 1/4] SQL/JSON functions (without sql_json GUC)

---
 doc/src/sgml/func.sgml                        | 2027 +++++++++++++++++
 doc/src/sgml/keywords/sql2016-02-reserved.txt |    3 +
 src/backend/executor/execExpr.c               |  349 ++-
 src/backend/executor/execExprInterp.c         |  726 ++++++
 src/backend/jit/llvm/llvmjit_expr.c           |   18 +
 src/backend/jit/llvm/llvmjit_types.c          |    3 +
 src/backend/nodes/copyfuncs.c                 |  453 ++++
 src/backend/nodes/equalfuncs.c                |  353 +++
 src/backend/nodes/makefuncs.c                 |  103 +
 src/backend/nodes/nodeFuncs.c                 |  458 ++++
 src/backend/nodes/outfuncs.c                  |  141 ++
 src/backend/nodes/readfuncs.c                 |  177 ++
 src/backend/optimizer/path/costsize.c         |    3 +-
 src/backend/optimizer/util/clauses.c          |   78 +
 src/backend/parser/gram.y                     |  765 ++++++-
 src/backend/parser/parse_collate.c            |    4 +
 src/backend/parser/parse_expr.c               | 1466 ++++++++++++
 src/backend/parser/parse_target.c             |   37 +
 src/backend/parser/parser.c                   |   16 +
 src/backend/utils/adt/format_type.c           |    4 +
 src/backend/utils/adt/formatting.c            |   45 +-
 src/backend/utils/adt/json.c                  |  572 ++++-
 src/backend/utils/adt/jsonb.c                 |  350 ++-
 src/backend/utils/adt/jsonb_util.c            |   24 +-
 src/backend/utils/adt/jsonfuncs.c             |   70 +-
 src/backend/utils/adt/jsonpath.c              |  257 +++
 src/backend/utils/adt/jsonpath_exec.c         |  350 ++-
 src/backend/utils/adt/ruleutils.c             |  436 +++-
 src/backend/utils/misc/queryjumble.c          |   69 +
 src/include/catalog/pg_aggregate.dat          |   22 +
 src/include/catalog/pg_proc.dat               |   70 +
 src/include/executor/execExpr.h               |   81 +
 src/include/executor/executor.h               |    2 +
 src/include/nodes/makefuncs.h                 |   10 +
 src/include/nodes/nodes.h                     |   23 +
 src/include/nodes/parsenodes.h                |  203 ++
 src/include/nodes/primnodes.h                 |  222 ++
 src/include/parser/kwlist.h                   |   22 +
 src/include/utils/formatting.h                |    4 +
 src/include/utils/json.h                      |   26 +
 src/include/utils/jsonb.h                     |   33 +
 src/include/utils/jsonfuncs.h                 |    7 +
 src/include/utils/jsonpath.h                  |   33 +
 src/interfaces/ecpg/preproc/parse.pl          |    2 +
 src/interfaces/ecpg/preproc/parser.c          |   14 +
 src/test/regress/expected/json_sqljson.out    |   15 +
 src/test/regress/expected/jsonb_sqljson.out   | 1018 +++++++++
 src/test/regress/expected/opr_sanity.out      |    6 +-
 src/test/regress/expected/sqljson.out         | 1268 +++++++++++
 src/test/regress/parallel_schedule            |    2 +-
 src/test/regress/sql/json_sqljson.sql         |   11 +
 src/test/regress/sql/jsonb_sqljson.sql        |  317 +++
 src/test/regress/sql/opr_sanity.sql           |    6 +-
 src/test/regress/sql/sqljson.sql              |  445 ++++
 54 files changed, 12919 insertions(+), 300 deletions(-)
 create mode 100644 src/test/regress/expected/json_sqljson.out
 create mode 100644 src/test/regress/expected/jsonb_sqljson.out
 create mode 100644 src/test/regress/expected/sqljson.out
 create mode 100644 src/test/regress/sql/json_sqljson.sql
 create mode 100644 src/test/regress/sql/jsonb_sqljson.sql
 create mode 100644 src/test/regress/sql/sqljson.sql

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 8a802fb225..891d237de1 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17564,6 +17564,1924 @@ $.* ? (@ like_regex "^\\d+$")
     </para>
    </sect3>
   </sect2>
+
+ <sect2 id="functions-sqljson">
+  <title>SQL/JSON Functions and Expressions</title>
+  <indexterm zone="functions-json">
+    <primary>SQL/JSON</primary>
+    <secondary>functions and expressions</secondary>
+  </indexterm>
+
+ <para>
+  To provide native support for JSON data types within the SQL environment,
+  <productname>PostgreSQL</productname> implements the
+  <firstterm>SQL/JSON data model</firstterm>.
+  This model comprises sequences of items. Each item can hold SQL scalar values,
+  with an additional SQL/JSON null value, and composite data structures that use JSON
+  arrays and objects.
+ </para>
+
+ <para>
+  SQL/JSON enables you to handle JSON data alongside regular SQL data,
+  with transaction support:
+ </para>
+
+ <itemizedlist>
+  <listitem>
+    <para>
+      Upload JSON data into a relational database and store it in
+      regular SQL columns as character or binary strings.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Generate JSON objects and arrays from relational data.
+    </para>
+  </listitem>
+  <listitem>
+    <para>
+      Query JSON data using SQL/JSON query functions and SQL/JSON path
+      language expressions.
+    </para>
+  </listitem>
+ </itemizedlist>
+
+ <para>
+   All SQL/JSON functions fall into one of two groups.
+   <link linkend="functions-sqljson-producing">Constructor functions</link>
+   generate JSON data from values of SQL types.
+   <link linkend="functions-sqljson-querying">Query functions</link>
+   evaluate SQL/JSON path language expressions against JSON values
+   and produce values of SQL/JSON types, which are converted to SQL types.
+ </para>
+
+  <sect3 id="functions-sqljson-producing">
+   <title>Producing JSON Content</title>
+
+  <para>
+    <productname>PostgreSQL</productname> provides several functions
+    that generate JSON data. Taking values of SQL types as input, these
+    functions construct JSON objects, JSON arrays or JSON scalars represented
+    as <type>json</type> or <type>jsonb</type> types, SQL character or binary strings.
+  </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonparse"><literal>JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonscalar"><literal>JSON_SCALAR</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobject"><literal>JSON_OBJECT</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonobjectagg"><literal>JSON_OBJECTAGG</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarray"><literal>JSON_ARRAY</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonarrayagg"><literal>JSON_ARRAYAGG</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <sect4 id="functions-jsonparse">
+   <title><literal>JSON</literal></title>
+   <indexterm><primary>json</primary></indexterm>
+<synopsis>
+<function>JSON</function> (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON</function> function generates a <acronym>JSON</acronym>
+      from a text data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          String expression that provides the <acronym>JSON</acronym> text data.
+          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          or binary strings (<type>bytea</type>) in UTF8 encoding.
+          For null input, <acronym>SQL</acronym> null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         Defines whether duplicate keys are allowed:
+        </para>
+        <variablelist>
+         <varlistentry>
+          <term><literal>WITHOUT</literal></term>
+          <listitem>
+           <para>
+            Default. The constructed
+            <acronym>JSON</acronym> object can contain duplicate keys.
+           </para>
+          </listitem>
+         </varlistentry>
+         <varlistentry>
+          <term><literal>WITH</literal></term>
+           <listitem>
+            <para>
+             Duplicate keys are not allowed.
+             If the input data contains duplicate keys, an error is returned.
+            </para>
+           </listitem>
+         </varlistentry>
+        </variablelist>
+        <para>
+         Optionally, you can add the <literal>KEYS</literal> keyword for
+         semantic clarity.
+        </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym>.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
+                       json                       
+--------------------------------------------------
+ { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
+(1 row)
+
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
+               json               
+----------------------------------
+ {"a": "bar", "b": [true, "foo"]}
+(1 row)
+
+SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+</screen>
+    </sect5>
+   </sect4>
+
+  <sect4 id="functions-jsonscalar">
+   <title><literal>JSON_SCALAR</literal></title>
+   <indexterm><primary>json_scalar</primary></indexterm>
+
+<synopsis>
+<function>JSON_SCALAR</function> (
+  <parameter>expression</parameter>
+  <optional> RETURNING <replaceable class="parameter">json_data_type</replaceable> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SCALAR</function> function generates a scalar
+      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter></literal>
+        </term>
+        <listitem>
+         <para>
+          Expression that provides the data for constructing a
+          <acronym>JSON</acronym>.
+          For null input, <acronym>SQL</acronym>  null
+          (not a <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number, a Boolean, the text representation
+          will be used, with escaping as necessary to make it a valid
+          <acronym>JSON</acronym> string value.
+          For details, see
+          <function>to_json()</function>/<function>to_jsonb()</function>
+          in <xref linkend="functions-json-creation-table"/>.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">json_data_type</replaceable></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the type (<type>json</type> or
+         <type>jsonb</type>) of the generated <acronym>JSON</acronym> scalar.
+         </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> objects by
+      using <productname>PostgreSQL</productname>-specific
+      <function>to_json()</function>/<function>to_jsonb()</function> functions.
+      See <xref linkend="functions-json-creation-table"/> for details.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON from the provided values various types:
+     </para>
+<screen>
+SELECT JSON_SCALAR(123.45);
+ json_scalar
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR('123');
+ json_scalar
+-------------
+ "123"
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar
+-------------
+ true
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobject">
+    <title><literal>JSON_OBJECT</literal></title>
+    <indexterm><primary>json_object</primary></indexterm>
+
+<synopsis>
+<function>JSON_OBJECT</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' }
+      <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> }<optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECT</function> function generates a <acronym>JSON</acronym>
+      object from <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+
+   <varlistentry>
+    <term>
+      <literal>
+       <parameter>key_expression</parameter> { VALUE | ':' }
+       <parameter>value_expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+      </literal>
+    </term>
+    <listitem>
+    <para>
+      The input clause that provides the data for constructing a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression
+              that provides the input for the <acronym>JSON</acronym> value.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              The optional <literal>FORMAT</literal> clause is provided to
+              conform to the SQL/JSON standard.
+             </para>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a
+        delimiter between the key and the value. Multiple key/value pairs are
+        separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+       Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can construct <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_object()</function>/
+  <function>jsonb_build_object()</function> functions.
+  See <xref linkend="functions-json-creation-table"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+   Construct a JSON object from the provided key/value pairs of various types:
+  </para>
+<screen>
+SELECT JSON_OBJECT(
+-- scalar JSON types
+ 'key1': 'string',
+ 'key2': '[1, 2]',
+ 'key3' VALUE 123, -- alternative syntax for key-value delimiter
+ 'key4': NULL,
+-- other types
+ 'key5': ARRAY[1, 2, 3], -- postgres array
+ 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
+ 'key7': date '2017-09-30', -- datetime type
+ 'key8': row(1, 'a'), -- row type
+ 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
+-- key can be an expression
+  'key' || 'last' : TRUE
+ABSENT ON NULL) AS json;
+                       json
+----------------------------------------------------
+{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
+ "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
+ "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
+ "key9" : [1, 2], "keylast" : true}
+(1 row)
+</screen>
+
+  <para>
+   From the <structname>films</structname> table, select some data
+   about the films distributed by Paramount Pictures
+   (<literal>did</literal> = 103) and return JSON objects:
+  </para>
+<screen>
+SELECT
+JSON_OBJECT(
+ 'code' VALUE f.code,
+ 'title' VALUE f.title,
+ 'did' VALUE f.did
+) AS paramount
+FROM films AS f
+WHERE f.did = 103;
+                    paramount
+----------------------------------------------------
+{"code" : "P_301", "title" : "Vertigo", "did" : 103}
+{"code" : "P_302", "title" : "Becket", "did" : 103}
+{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
+(3 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonobjectagg">
+   <title><literal>JSON_OBJECTAGG</literal></title>
+   <indexterm><primary>json_objectagg</primary></indexterm>
+   
+<synopsis>
+<function>JSON_OBJECTAGG</function> (
+  <optional> { <parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter> } </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_OBJECTAGG</function> function aggregates the provided data
+      into a <acronym>JSON</acronym> object. You can use this function to combine values
+      stored in different table columns into pairs. If you specify a <command>GROUP BY</command>
+      or an <command>ORDER BY</command> clause, this function returns a separate JSON object
+      for each table row.
+    </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><parameter>key_expression</parameter> { VALUE | ':' } <parameter>value_expression</parameter></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause that provides the data to be aggregated as a <acronym>JSON</acronym> object:
+    </para>
+        <itemizedlist>
+          <listitem>
+            <para>
+              <parameter>key_expression</parameter> is a scalar expression
+              defining the <acronym>JSON</acronym> key, which is implicitly
+              converted to the <type>text</type> type.
+              The provided expression cannot be <literal>NULL</literal> or
+              belong to a type that has a cast to <type>json</type>.
+            </para>
+          </listitem>
+          <listitem>
+            <para>
+              <parameter>value_expression</parameter> is an expression that
+              provides the input for the <acronym>JSON</acronym> value preceded
+              by its type.
+              For <acronym>JSON</acronym> scalar types, you can omit the type.
+            </para>
+            <note>
+              <para>
+                The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+                and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+                <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+              </para>
+            </note>
+           </listitem>
+           </itemizedlist>
+      <para>
+        You must use a colon or the <literal>VALUE</literal> keyword as a delimiter between
+        keys and values. Multiple key/value pairs are separated by commas.
+      </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed
+        <acronym>JSON</acronym> object:
+        </para>
+      <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              Default. <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      </listitem>
+    </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+     </para>
+        <variablelist>
+         <varlistentry>
+           <term><literal>WITHOUT</literal></term>
+           <listitem>
+             <para>
+              Default. The constructed
+              <acronym>JSON</acronym> object can contain duplicate keys.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>WITH</literal></term>
+            <listitem>
+             <para>
+              Duplicate keys are not allowed.
+              If the input data contains duplicate keys, an error is returned.
+              This check is performed before removing JSON items with NULL values.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+      <para>
+        Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the type of the generated <acronym>JSON</acronym> object.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+  </variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> objects by using
+  <productname>PostgreSQL</productname>-specific <function>json_object_agg()</function>/
+  <function>jsonb_object_agg()</function> aggregate functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    For films with <literal>did</literal> = 103, aggregate key/value pairs
+    of film genre (<literal>f.kind</literal>) and title (<literal>f.title</literal>)
+    into a single object:
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+ f.kind VALUE f.title)
+ AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
+</screen>
+
+  <para>
+    Return the same object as <type>jsonb</type>. Note that only a single film of
+    the action genre is included as the <type>jsonb</type> type does not allow duplicate keys.
+  </para>
+<screen>
+SELECT
+JSON_OBJECTAGG(
+  f.kind VALUE f.title
+  RETURNING jsonb)
+AS films_list
+FROM films AS f
+where f.did = 103;
+                 films_list
+----------------------------------------------------
+{"Drama": "Becket", "Action": "48 Hrs"}
+</screen>
+
+  <para>
+    Return objects of film titles and length, grouped by the film genre:
+  </para>
+<screen>
+SELECT
+  f.kind,
+  JSON_OBJECTAGG(
+    f.title VALUE f.len
+) AS films_list
+FROM films AS f
+GROUP BY f.kind;
+
+     kind    |        films_list
+-------------+----------------------------------
+Musical      | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
+Romantic     | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
+Comedy       | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
+Drama        | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
+Action       | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarray">
+    <title><literal>JSON_ARRAY</literal></title>
+    <indexterm><primary>json_array</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAY</function> (
+  <optional> { <parameter>value_expression</parameter> <optional> FORMAT JSON </optional> } <optional>, ...</optional> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+<synopsis>JSON_ARRAY (
+  <optional> <replaceable class="parameter">query_expression</replaceable> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAY</function> function constructs a <acronym>JSON</acronym> array from
+      the provided <acronym>SQL</acronym> or <acronym>JSON</acronym> data.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the data for constructing a JSON array.
+          The <replaceable class="parameter">value_expression</replaceable> is an expression
+          that provides the input for the <acronym>JSON</acronym> value preceded by its type.
+          For <acronym>JSON</acronym> scalar types, you can omit the type.
+        </para>
+        <note>
+          <para>
+            The input value of the <literal>bytea</literal> type must be stored in <literal>UTF8</literal>
+            and contain a valid <literal>UTF8</literal> string. Otherwise, an error occurs.
+            <productname>PostgreSQL</productname> currently supports only <literal>UTF8</literal>.
+          </para>
+        </note>
+
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+      <term>
+        <literal><replaceable class="parameter">query_expression</replaceable></literal>
+      </term>
+      <listitem>
+        <para>
+          An SQL query that provides the data for constructing a JSON array.
+          The query must return a single column that holds the values to be
+          used in the array.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the generated <acronym>JSON</acronym> array:
+      </para>
+       <variablelist>
+         <varlistentry>
+           <term><literal>NULL</literal></term>
+           <listitem>
+             <para>
+              <literal>NULL</literal> values are allowed.
+             </para>
+            </listitem>
+          </varlistentry>
+          <varlistentry>
+           <term><literal>ABSENT</literal></term>
+            <listitem>
+             <para>
+              Default. If the value is <literal>NULL</literal>,
+              the corresponding key/value pair is omitted from the generated
+              <acronym>JSON</acronym> object.
+             </para>
+            </listitem>
+          </varlistentry>
+        </variablelist>
+        <para>
+          This clause is only supported for arrays built from an explicit list of values.
+          If you are using an SQL query to generate an array, NULL values are always
+          omitted.
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+      </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+ <sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_build_array()</function>/
+  <function>jsonb_build_array()</function> functions.
+  See <xref linkend="functions-json"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+  <para>
+    From the <structname>films</structname> table, select some data
+    about the films distributed by Paramount Pictures
+    (<literal>did</literal> = 103) and return JSON arrays:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  f.code,
+  f.title,
+  f.did
+) AS films
+FROM films AS f
+WHERE f.did = 103;
+                       films
+----------------------------------------------------
+["code" : "P_301", "title" : "Vertigo", "did" : 103]
+["code" : "P_302", "title" : "Becket", "did" : 103]
+["code" : "P_303", "title" : "48 Hrs", "did" : 103]
+(3 rows)
+</screen>
+  <para>
+    Construct a JSON array from the list of film titles returned from the
+    <structname>films</structname> table by a subquery:
+  </para>
+<screen>
+SELECT
+JSON_ARRAY(
+  SELECT
+  f.title
+FROM films AS f
+where f.did = 103)
+AS film_titles;
+                    film_titles
+----------------------------------------------------
+["Vertigo", "Becket", "48 Hrs"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonarrayagg">
+    <title><literal>JSON_ARRAYAGG</literal></title>
+    <indexterm><primary>json_arrayagg</primary></indexterm>
+
+<synopsis>
+<function>JSON_ARRAYAGG</function> (
+  <optional> <parameter>value_expression</parameter> </optional>
+  <optional> ORDER BY <replaceable class="parameter">sort_expression</replaceable> </optional>
+  <optional> { NULL | ABSENT } ON NULL </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      The <function>JSON_ARRAYAGG</function> function aggregates the provided <acronym>SQL</acronym>
+      or <acronym>JSON</acronym> data into a <acronym>JSON</acronym> array.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+      <term>
+        <literal><parameter>value_expression</parameter></literal>
+      </term>
+      <listitem>
+
+        <para>
+          The input clause that provides the input data to be aggregated as
+          a <acronym>JSON</acronym> array.
+          The <parameter>value_expression</parameter> can be a value or a query
+          returning the values to be used as input in array construction.
+          You can provide multiple input values separated by commas.
+        </para>
+    </listitem>
+   </varlistentry>
+
+<varlistentry>
+      <term>
+        <literal>ORDER BY</literal>
+      </term>
+      <listitem>
+        <para>
+          Sorts the input data to be aggregated as a <acronym>JSON</acronym> array.
+          For details on the exact syntax of the <literal>ORDER BY</literal> clause, see <xref linkend="sql-orderby"/>.
+        </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ NULL | ABSENT } ON NULL</literal>
+    </term>
+    <listitem>
+      <para>
+        Defines whether <literal>NULL</literal> values are allowed in the constructed array:
+          <itemizedlist>
+            <listitem>
+              <para>
+                <literal>NULL</literal> &mdash; <literal>NULL</literal> values are allowed.
+              </para>
+            </listitem>
+            <listitem>
+              <para>
+                <literal>ABSENT</literal> (default) &mdash; <literal>NULL</literal>
+                values are omitted from the generated array.
+              </para>
+            </listitem>
+          </itemizedlist>
+        </para>
+      </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the constructed <acronym>JSON</acronym> array.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+</variablelist>
+    </sect5>
+
+<sect5>
+  <title>Notes</title>
+  <para>Alternatively, you can create <acronym>JSON</acronym> arrays by using
+  <productname>PostgreSQL</productname>-specific <function>json_agg()</function>/
+  <function>jsonb_agg()</function> functions.
+  See <xref linkend="functions-aggregate"/> for details.
+  </para>
+ </sect5>
+
+    <sect5>
+     <title>Examples</title>
+     <para>
+       Construct an array of film titles sorted in alphabetical order:
+     </para>
+<screen>
+SELECT
+JSON_ARRAYAGG(
+  f.title
+ORDER BY f.title ASC) AS film_titles
+FROM films AS f;
+                    film_titles
+----------------------------------------------------
+["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+  </sect3>
+
+  <sect3 id="functions-sqljson-querying">
+   <title>Querying JSON</title>
+
+   <para>
+    SQL/JSON query functions evaluate SQL/JSON path language expressions
+    against JSON values, producing values of SQL/JSON types, which are
+    converted to SQL types. All SQL/JSON query functions accept several
+    common clauses described in <xref linkend="sqljson-common-clauses"/>.
+    For details on the SQL/JSON path language,
+    see <xref linkend="functions-sqljson-path"/>.
+   </para>
+
+  <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-isjson-predicate"><literal>IS JSON</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonexists"><literal>JSON_EXISTS</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonvalue"><literal>JSON_VALUE</literal></link>
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
+      </para>
+    </listitem>
+  </itemizedlist>
+
+  <para>
+     In some usage examples for these functions,
+     the following small table storing some JSON data will be used:
+<programlisting>
+CREATE TABLE my_films (
+  js       text );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+   { "kind" : "comedy", "films" : [
+     { "title" : "Bananas",
+       "director" : "Woody Allen"},
+     { "title" : "The Dinner Game",
+       "director" : "Francis Veber" } ] },
+   { "kind" : "horror", "films" : [
+     { "title" : "Psycho",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "thriller", "films" : [
+     { "title" : "Vertigo",
+       "director" : "Alfred Hitchcock" } ] },
+   { "kind" : "drama", "films" : [
+     { "title" : "Yojimbo",
+       "director" : "Akira Kurosawa" } ] }
+  ] }');
+</programlisting>
+     </para>
+
+   <sect4 id="functions-jsonexists">
+    <title><literal>JSON_EXISTS</literal></title>
+    <indexterm><primary>json_exists</primary></indexterm>
+
+<synopsis>
+<function>JSON_EXISTS</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_EXISTS</function> function checks whether the provided
+      <acronym>JSON</acronym> path expression can return any <acronym>SQL/JSON</acronym> items.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     See <xref linkend="sqljson-input-clause"/> for details.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       The specified data type should have a cast from a <literal>boolean</literal>
+       type, which is returned by default.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an error occurs. The default value is <literal>FALSE</literal>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+  <para>
+    Check whether the provided <type>jsonb</type> data contains a
+    key/value pair with the <literal>key1</literal> key, and its value
+    contains an array with one or more elements bigger than 2:
+  </para>
+<screen>
+SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
+ json_exists
+-------------
+ t
+(1 row)
+</screen>
+
+  <para>
+   Note the difference between strict and lax modes
+   if the required item does not exist:
+  </para>
+<screen>
+-- Strict mode with ERROR on ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
+ERROR: Invalid SQL/JSON subscript
+(1 row)
+</screen>
+
+<screen>
+-- Lax mode
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+<screen>
+-- Strict mode using the default value for the ON ERROR clause
+SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
+ json_exists
+-------------
+ f
+(1 row)
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonvalue">
+    <title><literal>JSON_VALUE</literal></title>
+    <indexterm><primary>json_value</primary></indexterm>
+
+<synopsis>
+<function>JSON_VALUE</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_VALUE</function> function extracts a value from the provided
+   <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
+   If the specified JSON path expression returns more than one
+   <acronym>SQL/JSON</acronym> item, an error occurs. To extract
+   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <literal>json</literal>, <literal>jsonb</literal>,
+       <literal>bytea</literal>, and character string types (<literal>text</literal>, <literal>char</literal>,
+       <literal>varchar</literal>, and <literal>nchar</literal>).
+       The extracted value must be a single <acronym>SQL/JSON</acronym> scalar item
+       and have a cast to the specified type. Otherwise, an error occurs.
+       By default, <function>JSON_VALUE</function> returns a string
+       of the <literal>text</literal> type.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is
+       <literal>NULL</literal>. If you use
+       <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is
+       evaluated and cast to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract an SQL/JSON value and return it as an SQL
+      scalar of the specified type. Note that
+      <command>JSON_VALUE</command> can only return a
+      single scalar, and the returned value must have a
+      cast to the specified return type:
+     </para>
+
+<screen>
+SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+ json_value
+------------
+     123.45
+(1 row)
+
+SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+ json_value
+------------
+        123
+(1 row)
+
+SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+ json_value 
+------------
+ 2015-02-01
+(1 row)
+
+SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for integer: "123.45"
+
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+</screen>
+
+     <para>
+       If the path expression returns an array, an object, or
+       multiple SQL/JSON items, an error is returned, as specified
+       in the <command>ON ERROR</command> clause:
+     </para>
+<screen>
+SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
+ERROR: SQL/JSON scalar required
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
+ERROR: more than one SQL/JSON item
+
+SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
+1
+</screen>
+
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-jsonquery">
+    <title><literal>JSON_QUERY</literal></title>
+    <indexterm><primary>json_query</primary></indexterm>
+
+<synopsis>
+<function>JSON_QUERY</function> (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+  <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+  <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY </optional>
+  <optional> { ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR </optional>
+)
+  </synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   array or object from <acronym>JSON</acronym> data. This function must return
+   a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
+   items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
+   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+   <variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query, and an optional <literal>PASSING</literal> clause.
+     For details, see <xref linkend="functions-sqljson-path"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the data type of the returned value.
+       For details, see <xref linkend="sqljson-output-clause"/>.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to wrap a returned sequence of <acronym>SQL/JSON</acronym>
+       items into a <acronym>SQL/JSON</acronym> array.
+     </para>
+       <variablelist>
+        <varlistentry>
+        <term><literal>WITHOUT WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Do not wrap the result.
+            This is the default behavior if the <literal>WRAPPER</literal>
+            clause is omitted.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH <optional>UNCONDITIONAL</optional> WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Always wrap the result.
+          </para>
+        </listitem>
+        </varlistentry>
+        <varlistentry>
+        <term><literal>WITH CONDITIONAL WRAPPER</literal></term>
+        <listitem>
+          <para>
+            Wrap the result if the path
+            expression returns anything other than a single
+            <acronym>SQL/JSON</acronym> array or object.
+          </para>
+        </listitem>
+        </varlistentry>
+       </variablelist>
+     <para>
+       Optionally, you can add the <literal>ARRAY</literal> keyword for semantic clarity.
+     </para>
+     <important>
+      <para>You cannot use this clause together with the <literal>ON EMPTY</literal> clause.
+      </para>
+     </important>
+     </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>{ KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       Defines whether to keep or omit quotes if a scalar string is returned.
+       By default, scalar strings are returned with quotes. Using this
+       clause together with the <command>WITH WRAPPER</command> clause is not allowed.
+     </para>
+     <para>
+       Optionally, you can add the <literal>ON SCALAR STRING</literal> keywords for semantic clarity.
+     </para>
+     </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON EMPTY</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if no JSON value is found. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array [] or object {} is returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     <para>
+       You cannot use this clause together with the <literal>WRAPPER</literal> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+     <varlistentry>
+    <term>
+     <literal>{ ERROR | NULL | EMPTY { <optional> ARRAY </optional> | OBJECT } | DEFAULT <replaceable class="parameter">expression</replaceable> } ON ERROR</literal>
+    </term>
+    <listitem>
+     <para>
+       Defines the return value if an unhandled error occurs. The default is <literal>NULL</literal>.
+       If you use <literal>EMPTY <optional>ARRAY</optional></literal> or <literal>EMPTY OBJECT</literal>,
+       an empty JSON array <literal>[]</literal> or object <literal>{}</literal> are returned, respectively.
+       If you use <literal>DEFAULT <replaceable class="parameter">expression</replaceable></literal>,
+       the provided <replaceable class="parameter">expression</replaceable> is evaluated and cast
+       to the type specified in the <command>RETURNING</command> clause.
+     </para>
+     </listitem>
+   </varlistentry>
+
+   </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Extract all film genres listed in the <structname>my_films</structname> table:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
+FROM my_films;
+ json_query
+------------
+ ["comedy", "horror", "thriller", "drama"]
+(1 row)
+</screen>
+
+     <para>
+      Note that the same query will result in an error if you omit the
+      <command>WITH WRAPPER</command> clause, as it returns multiple SQL/JSON items:
+     </para>
+     <screen>
+SELECT
+    JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
+FROM my_films;
+ERROR: more than one SQL/JSON item 
+</screen>
+
+     <para>
+       Compare the effect of different <literal>WRAPPER</literal> clauses:
+     </para>
+     <screen>
+SELECT
+    js,
+    JSON_QUERY(js, 'lax $[*]') AS "without",
+    JSON_QUERY(js, 'lax $[*]' WITH WRAPPER)  AS "with uncond",
+    JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+FROM
+    (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'),  ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
+       js       |  without  |  with uncond   |   with cond
+----------------+-----------+----------------+----------------
+ []             | (null)    | (null)         | (null)
+ [1]            | 1         | [1]            | [1]
+ [[1, 2, 3]]    | [1, 2, 3] | [[1, 2, 3]]    | [1, 2, 3]
+ [{"a": 1}]     | {"a": 1}  | [{"a": 1}]     | {"a": 1}
+ [1, null, "2"] | (null)    | [1, null, "2"] | [1, null, "2"]
+(5 rows)
+</screen>
+
+<para>Compare quote handling for scalar types with and without the <command>OMIT QUOTES</command> clause:
+</para>
+     <screen>
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query
+------------
+ aaa
+(1 row)
+</screen>
+    </sect5>
+   </sect4>
+
+   <sect4 id="functions-isjson-predicate">
+    <title><literal>IS JSON</literal></title>
+    <indexterm><primary>is_json</primary></indexterm>
+
+<synopsis>
+<replaceable class="parameter">expression</replaceable>
+  IS <optional> NOT </optional> JSON 
+  <optional> { VALUE | SCALAR | ARRAY | OBJECT } </optional>
+  <optional> { WITH | WITHOUT } UNIQUE <optional> KEYS </optional> </optional>
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+  <para>
+   The <command>IS JSON</command> predicate tests whether the provided value is valid
+   <acronym>JSON</acronym> data. If you provide a specific JSON data type as a parameter,
+   you can check whether the value belongs to this type.
+   You can also use this predicate in the <command>IS NOT JSON</command> form.
+   The return values are:
+   <itemizedlist>
+    <listitem>
+      <para>
+        <literal>t</literal> if the value satisfies the specified condition.
+      </para>
+    </listitem>
+    <listitem>
+      <para>
+        <literal>f</literal> if the value does not satisfy the specified condition.
+      </para>
+    </listitem>
+   </itemizedlist>
+  </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+
+<variablelist>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable class="parameter">expression</replaceable></literal>
+    </term>
+    <listitem>
+
+    <para>
+      The input clause defining the value to test. You can provide the values
+      of <literal>json</literal>, <literal>jsonb</literal>,
+      <literal>bytea</literal>, or character string types.
+    </para>
+  </listitem>
+   </varlistentry>
+   
+   <varlistentry>
+    <term>
+     <literal>VALUE | SCALAR | ARRAY | OBJECT</literal>
+    </term>
+    <listitem>
+
+    <para>
+      Specifies the <acronym>JSON</acronym> data type to test for:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>VALUE</literal> (default) &mdash; any <acronym>JSON</acronym> type.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>SCALAR</literal> &mdash; <acronym>JSON</acronym> number, string, or boolean.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>ARRAY</literal> &mdash; <acronym>JSON</acronym> array.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>OBJECT</literal> &mdash; <acronym>JSON</acronym> object.
+          </para>
+        </listitem>
+      </itemizedlist>
+    </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+    <term>
+     <literal>{ WITH | WITHOUT } UNIQUE <optional> KEYS </optional></literal>
+    </term>
+    <listitem>
+     <para>Defines whether duplicate keys are allowed:
+      <itemizedlist>
+        <listitem>
+          <para>
+            <literal>WITHOUT</literal> (default) &mdash; the
+            <acronym>JSON</acronym> object can contain duplicate keys.
+          </para>
+        </listitem>
+        <listitem>
+          <para>
+            <literal>WITH</literal> &mdash; duplicate keys are not allowed.
+            If the input data contains duplicate keys, it is considered to be invalid JSON.
+          </para>
+        </listitem>
+      </itemizedlist>
+      Optionally, you can add the <literal>KEYS</literal> keyword for semantic clarity.
+      </para>
+    </listitem>
+  </varlistentry>
+   </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Compare the result returned by the <function>IS JSON</function>
+      predicate for different data types:
+     </para>
+     <screen>
+SELECT
+    js, 
+    js IS JSON "is json", 
+    js IS NOT JSON "is not json",
+    js IS JSON SCALAR "is scalar",
+    js IS JSON OBJECT "is object",
+    js IS JSON ARRAY "is array"
+FROM 
+    (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+     js     | is json | is not json | is scalar | is object | is array 
+------------+---------+-------------+-----------+-----------|-------------
+ 123        | t       | f           | t         | f         | f
+ "abc"      | t       | f           | t         | f         | f
+ {"a": "b"} | t       | f           | f         | t         | f
+ [1,2]      | t       | f           | f         | f         | t
+ abc        | f       | t           | f         | f         | f
+(5 rows)
+</screen>
+    </sect5>
+   </sect4>
+
+
+  </sect3>
+
+  <sect3 id="functions-sqljson-serializing">
+   <title>Serializing JSON data</title>
+   <itemizedlist>
+    <listitem>
+      <para>
+       <link linkend="functions-jsonserialize"><literal>JSON_SERIALIZE</literal></link>
+      </para>
+    </listitem>
+   </itemizedlist>
+
+   <sect4 id="functions-jsonserialize">
+    <title><literal>JSON_SERIALAIZE</literal></title>
+    <indexterm><primary>json_serialize</primary></indexterm>
+
+<synopsis>
+JSON_SERIALIZE (
+  <parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional>
+  <optional> RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional> </optional>
+)
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_SERIALIZE</function> function transforms a SQL/JSON value
+      into a character or binary string.
+     </para>
+    </sect5>
+
+    <sect5>
+     <title>Parameters</title>
+      <variablelist>
+       <varlistentry>
+        <term>
+         <literal><parameter>expression</parameter> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+         <para>
+          <acronym>JSON</acronym> typed expression that provides a data for
+          serialization.  Accepted JSON types (<type>json</type> and
+          <type>jsonb</type>), any character string types (<type>text</type>,
+          <type>char</type>, etc.), binary strings (<type>bytea</type>) in
+          UTF8 encoding.
+          For null input, null value is returned.
+         </para>
+         <para>
+           The optional <literal>FORMAT</literal> clause is provided to conform
+           to the SQL/JSON standard.
+         </para>
+        </listitem>
+       </varlistentry>
+       <varlistentry>
+        <term>
+         <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+        </term>
+        <listitem>
+        <para>
+         The output clause that specifies the target character or binary string
+         type (<type>text</type>, <type>char</type>, <type>bytea</type>, etc.).
+        </para>
+       </listitem>
+      </varlistentry>
+     </variablelist>
+    </sect5>
+
+    <sect5>
+     <title>Notes</title>
+     <para>
+      Alternatively, you can construct <acronym>JSON</acronym> values simply
+      using <productname>PostgreSQL</productname>-specific casts to 
+      <type>json</type> and <type>jsonb</type> types.
+     </para>
+    </sect5>
+    <sect5>
+     <title>Examples</title>
+     <para>
+      Construct a JSON the provided strings:
+     </para>
+<screen>
+SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
+ json_serialize 
+----------------
+ "foo"
+(1 row)
+
+SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea);
+                           json_serialize                           
+--------------------------------------------------------------------
+ \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d
+(1 row)
+
+</screen>
+    </sect5>
+   </sect4>
+
+  </sect3>
+ 
+  <sect3 id="sqljson-common-clauses">
+   <title>SQL/JSON Common Clauses</title>
+
+   <sect4 id="sqljson-input-clause">
+    <title>SQL/JSON Input Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
+<optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The input clause specifies the JSON data to query and
+       the exact query path to be passed to SQL/JSON query functions:
+     </para>
+    <itemizedlist>
+     <listitem>
+      <para>
+       The <replaceable>context_item</replaceable> is the JSON data to query.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       The <replaceable>path_expression</replaceable> is an SQL/JSON path
+       expression that specifies the items to be retrieved from the JSON
+       data. For details on path expression syntax, see
+       <xref linkend="functions-sqljson-path"/>.
+      </para>
+      </listitem>
+      <listitem>
+      <para>
+       The optional <command>PASSING</command> clause provides the values for
+       the named variables used in the SQL/JSON path expression.
+      </para>
+     </listitem>
+    </itemizedlist>
+    <para>
+     The input clause is common for all SQL/JSON query functions.
+    </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+
+   <sect4 id="sqljson-output-clause">
+    <title>SQL/JSON Output Clause</title>
+
+    <variablelist>
+  <varlistentry>
+    <term>
+     <literal>RETURNING <replaceable class="parameter">data_type</replaceable> <optional> FORMAT JSON <optional> ENCODING UTF8 </optional> </optional></literal>
+    </term>
+    <listitem>
+     <para>
+       The output clause that specifies the return type of the generated
+       <acronym>JSON</acronym> object. Out of the box, <productname>PostgreSQL</productname>
+       supports the following types: <type>json</type>, <type>jsonb</type>,
+       <type>bytea</type>, and character string types (<type>text</type>, <type>char</type>,
+       <type>varchar</type>, and <type>nchar</type>).
+       To use other types, you must create the <literal>CAST</literal> from <type>json</type> for this type.
+       By default, the <type>json</type> type is returned.
+     </para>
+     <para>
+       The optional <literal>FORMAT</literal> clause is provided to conform to the SQL/JSON standard.
+      </para>
+     <para>
+       The output clause is common for both constructor and query SQL/JSON functions.
+     </para>
+     </listitem>
+   </varlistentry>
+    </variablelist>
+
+   </sect4>
+  </sect3>
+  </sect2>
+
  </sect1>
 
  <sect1 id="functions-sequence">
@@ -19719,6 +21637,115 @@ SELECT NULLIF(value, '(none)') ...
        </para></entry>
        <entry>No</entry>
       </row>
+      
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_agg_strict</primary>
+        </indexterm>
+        <function>json_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the input values, skipping nulls, into a JSON array.
+        Values are converted to JSON as per <function>to_json</function>
+        or <function>to_jsonb</function>.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_strict</primary>
+        </indexterm>
+        <function>json_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique</primary>
+        </indexterm>
+        <function>json_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Values can be null, but not keys.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
+
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>json_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>json_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>json</returnvalue>
+       </para>
+       <para role="func_signature">
+        <indexterm>
+         <primary>jsonb_object_agg_unique_strict</primary>
+        </indexterm>
+        <function>jsonb_object_agg_unique_strict</function> (
+         <parameter>key</parameter> <type>"any"</type>,
+         <parameter>value</parameter> <type>"any"</type> )
+        <returnvalue>jsonb</returnvalue>
+       </para>
+       <para>
+        Collects all the key/value pairs into a JSON object.  Key arguments
+        are coerced to text; value arguments are converted as
+        per <function>to_json</function> or <function>to_jsonb</function>.
+        Null values are skipped, keys can not be null.
+        In case of duplicate keys error is thrown.
+       </para></entry>
+       <entry>No</entry>
+      </row>
 
       <row>
        <entry role="func_table_entry"><para role="func_signature">
diff --git a/doc/src/sgml/keywords/sql2016-02-reserved.txt b/doc/src/sgml/keywords/sql2016-02-reserved.txt
index ae11012388..7ba4208398 100644
--- a/doc/src/sgml/keywords/sql2016-02-reserved.txt
+++ b/doc/src/sgml/keywords/sql2016-02-reserved.txt
@@ -156,12 +156,15 @@ INTERVAL
 INTO
 IS
 JOIN
+JSON
 JSON_ARRAY
 JSON_ARRAYAGG
 JSON_EXISTS
 JSON_OBJECT
 JSON_OBJECTAGG
 JSON_QUERY
+JSON_SCALAR
+JSON_SERIALIZE
 JSON_TABLE
 JSON_TABLE_PRIMITIVE
 JSON_VALUE
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index e0656bfe85..d4d3850ec7 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -47,6 +47,9 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/datum.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
@@ -85,6 +88,40 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 								  bool nullcheck);
 
 
+static ExprState *
+ExecInitExprInternal(Expr *node, PlanState *parent, ParamListInfo ext_params,
+					 Datum *caseval, bool *casenull)
+{
+	ExprState  *state;
+	ExprEvalStep scratch = {0};
+
+	/* Special case: NULL expression produces a NULL ExprState pointer */
+	if (node == NULL)
+		return NULL;
+
+	/* Initialize ExprState with empty step list */
+	state = makeNode(ExprState);
+	state->expr = node;
+	state->parent = parent;
+	state->ext_params = ext_params;
+	state->innermost_caseval = caseval;
+	state->innermost_casenull = casenull;
+
+	/* Insert EEOP_*_FETCHSOME steps as needed */
+	ExecInitExprSlots(state, (Node *) node);
+
+	/* Compile the expression proper */
+	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
+
+	/* Finally, append a DONE step */
+	scratch.opcode = EEOP_DONE;
+	ExprEvalPushStep(state, &scratch);
+
+	ExecReadyExpr(state);
+
+	return state;
+}
+
 /*
  * ExecInitExpr: prepare an expression tree for execution
  *
@@ -122,32 +159,7 @@ static void ExecBuildAggTransCall(ExprState *state, AggState *aggstate,
 ExprState *
 ExecInitExpr(Expr *node, PlanState *parent)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = parent;
-	state->ext_params = NULL;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
-
-	return state;
+	return ExecInitExprInternal(node, parent, NULL, NULL, NULL);
 }
 
 /*
@@ -159,32 +171,20 @@ ExecInitExpr(Expr *node, PlanState *parent)
 ExprState *
 ExecInitExprWithParams(Expr *node, ParamListInfo ext_params)
 {
-	ExprState  *state;
-	ExprEvalStep scratch = {0};
-
-	/* Special case: NULL expression produces a NULL ExprState pointer */
-	if (node == NULL)
-		return NULL;
-
-	/* Initialize ExprState with empty step list */
-	state = makeNode(ExprState);
-	state->expr = node;
-	state->parent = NULL;
-	state->ext_params = ext_params;
-
-	/* Insert EEOP_*_FETCHSOME steps as needed */
-	ExecInitExprSlots(state, (Node *) node);
-
-	/* Compile the expression proper */
-	ExecInitExprRec(node, state, &state->resvalue, &state->resnull);
-
-	/* Finally, append a DONE step */
-	scratch.opcode = EEOP_DONE;
-	ExprEvalPushStep(state, &scratch);
-
-	ExecReadyExpr(state);
+	return ExecInitExprInternal(node, NULL, ext_params, NULL, NULL);
+}
 
-	return state;
+/*
+ * ExecInitExprWithCaseValue: prepare an expression tree for execution
+ *
+ * This is the same as ExecInitExpr, except that a pointer to the value for
+ * CasTestExpr is passed here.
+ */
+ExprState *
+ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull)
+{
+	return ExecInitExprInternal(node, parent, NULL, caseval, casenull);
 }
 
 /*
@@ -2428,6 +2428,253 @@ ExecInitExprRec(Expr *node, ExprState *state,
 				break;
 			}
 
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				ExecInitExprRec(jve->raw_expr, state, resv, resnull);
+
+				if (jve->formatted_expr)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(jve->formatted_expr, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+				break;
+			}
+
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+				List	   *args = ctor->args;
+				ListCell   *lc;
+				int			nargs = list_length(args);
+				int			argno = 0;
+
+				if (ctor->func)
+				{
+					ExecInitExprRec(ctor->func, state, resv, resnull);
+				}
+				else if ((ctor->type == JSCTOR_JSON_PARSE && !ctor->unique) ||
+						 ctor->type == JSCTOR_JSON_SERIALIZE)
+				{
+					/* Use the value of the first argument as a result */
+					ExecInitExprRec(linitial(args), state, resv, resnull);
+				}
+				else
+				{
+					scratch.opcode = EEOP_JSON_CONSTRUCTOR;
+					scratch.d.json_constructor.constructor = ctor;
+					scratch.d.json_constructor.arg_values = palloc(sizeof(Datum) * nargs);
+					scratch.d.json_constructor.arg_nulls = palloc(sizeof(bool) * nargs);
+					scratch.d.json_constructor.arg_types = palloc(sizeof(Oid) * nargs);
+					scratch.d.json_constructor.nargs = nargs;
+
+					foreach(lc, args)
+					{
+						Expr	   *arg = (Expr *) lfirst(lc);
+
+						scratch.d.json_constructor.arg_types[argno] = exprType((Node *) arg);
+
+						if (IsA(arg, Const))
+						{
+							/* Don't evaluate const arguments every round */
+							Const	   *con = (Const *) arg;
+
+							scratch.d.json_constructor.arg_values[argno] = con->constvalue;
+							scratch.d.json_constructor.arg_nulls[argno] = con->constisnull;
+						}
+						else
+						{
+							ExecInitExprRec(arg, state,
+											&scratch.d.json_constructor.arg_values[argno],
+											&scratch.d.json_constructor.arg_nulls[argno]);
+						}
+						argno++;
+					}
+
+					/* prepare type cache for datum_to_json[b]() */
+					if (ctor->type == JSCTOR_JSON_SCALAR)
+					{
+						bool		is_jsonb =
+							ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+						scratch.d.json_constructor.arg_type_cache =
+							palloc(sizeof(*scratch.d.json_constructor.arg_type_cache) * nargs);
+
+						for (int i = 0; i < nargs; i++)
+						{
+							int			category;
+							Oid			outfuncid;
+							Oid			typid = scratch.d.json_constructor.arg_types[i];
+
+							if (is_jsonb)
+							{
+								JsonbTypeCategory jbcat;
+
+								jsonb_categorize_type(typid, &jbcat, &outfuncid);
+
+								category = (int) jbcat;
+							}
+							else
+							{
+								JsonTypeCategory jscat;
+
+								json_categorize_type(typid, &jscat, &outfuncid);
+
+								category = (int) jscat;
+							}
+
+							scratch.d.json_constructor.arg_type_cache[i].outfuncid = outfuncid;
+							scratch.d.json_constructor.arg_type_cache[i].category = category;
+						}
+					}
+
+					ExprEvalPushStep(state, &scratch);
+				}
+
+				if (ctor->coercion)
+				{
+					Datum	   *innermost_caseval = state->innermost_caseval;
+					bool	   *innermost_isnull = state->innermost_casenull;
+
+					state->innermost_caseval = resv;
+					state->innermost_casenull = resnull;
+
+					ExecInitExprRec(ctor->coercion, state, resv, resnull);
+
+					state->innermost_caseval = innermost_caseval;
+					state->innermost_casenull = innermost_isnull;
+				}
+			}
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				ExecInitExprRec((Expr *) pred->expr, state, resv, resnull);
+
+				scratch.opcode = EEOP_IS_JSON;
+				scratch.d.is_json.pred = pred;
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = castNode(JsonExpr, node);
+				ListCell   *argexprlc;
+				ListCell   *argnamelc;
+
+				scratch.opcode = EEOP_JSONEXPR;
+				scratch.d.jsonexpr.jsexpr = jexpr;
+
+				scratch.d.jsonexpr.formatted_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.formatted_expr));
+
+				ExecInitExprRec((Expr *) jexpr->formatted_expr, state,
+								&scratch.d.jsonexpr.formatted_expr->value,
+								&scratch.d.jsonexpr.formatted_expr->isnull);
+
+				scratch.d.jsonexpr.pathspec =
+					palloc(sizeof(*scratch.d.jsonexpr.pathspec));
+
+				ExecInitExprRec((Expr *) jexpr->path_spec, state,
+								&scratch.d.jsonexpr.pathspec->value,
+								&scratch.d.jsonexpr.pathspec->isnull);
+
+				scratch.d.jsonexpr.res_expr =
+					palloc(sizeof(*scratch.d.jsonexpr.res_expr));
+
+				scratch.d.jsonexpr.result_expr = jexpr->result_coercion
+					? ExecInitExprWithCaseValue((Expr *) jexpr->result_coercion->expr,
+												state->parent,
+												&scratch.d.jsonexpr.res_expr->value,
+												&scratch.d.jsonexpr.res_expr->isnull)
+					: NULL;
+
+				scratch.d.jsonexpr.default_on_empty = !jexpr->on_empty ? NULL :
+					ExecInitExpr((Expr *) jexpr->on_empty->default_expr,
+								 state->parent);
+
+				scratch.d.jsonexpr.default_on_error =
+					ExecInitExpr((Expr *) jexpr->on_error->default_expr,
+								 state->parent);
+
+				if (jexpr->omit_quotes ||
+					(jexpr->result_coercion && jexpr->result_coercion->via_io))
+				{
+					Oid			typinput;
+
+					/* lookup the result type's input function */
+					getTypeInputInfo(jexpr->returning->typid, &typinput,
+									 &scratch.d.jsonexpr.input.typioparam);
+					fmgr_info(typinput, &scratch.d.jsonexpr.input.func);
+				}
+
+				scratch.d.jsonexpr.args = NIL;
+
+				forboth(argexprlc, jexpr->passing_values,
+						argnamelc, jexpr->passing_names)
+				{
+					Expr	   *argexpr = (Expr *) lfirst(argexprlc);
+					String	   *argname = lfirst_node(String, argnamelc);
+					JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+					var->name = pstrdup(argname->sval);
+					var->typid = exprType((Node *) argexpr);
+					var->typmod = exprTypmod((Node *) argexpr);
+					var->estate = ExecInitExpr(argexpr, state->parent);
+					var->econtext = NULL;
+					var->evaluated = false;
+					var->value = (Datum) 0;
+					var->isnull = true;
+
+					scratch.d.jsonexpr.args =
+						lappend(scratch.d.jsonexpr.args, var);
+				}
+
+				scratch.d.jsonexpr.cache = NULL;
+
+				if (jexpr->coercions)
+				{
+					JsonCoercion **coercion;
+					struct JsonCoercionState *cstate;
+					Datum	   *caseval;
+					bool	   *casenull;
+
+					scratch.d.jsonexpr.coercion_expr =
+						palloc(sizeof(*scratch.d.jsonexpr.coercion_expr));
+
+					caseval = &scratch.d.jsonexpr.coercion_expr->value;
+					casenull = &scratch.d.jsonexpr.coercion_expr->isnull;
+
+					for (cstate = &scratch.d.jsonexpr.coercions.null,
+						 coercion = &jexpr->coercions->null;
+						 coercion <= &jexpr->coercions->composite;
+						 coercion++, cstate++)
+					{
+						cstate->coercion = *coercion;
+						cstate->estate = *coercion ?
+							ExecInitExprWithCaseValue((Expr *)(*coercion)->expr,
+													  state->parent,
+													  caseval, casenull) : NULL;
+					}
+				}
+
+				ExprEvalPushStep(state, &scratch);
+				break;
+			}
+
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 64bd17b62e..0d005dac13 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -57,22 +57,31 @@
 #include "postgres.h"
 
 #include "access/heaptoast.h"
+#include "access/xact.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/sequence.h"
 #include "executor/execExpr.h"
 #include "executor/nodeSubplan.h"
 #include "funcapi.h"
 #include "miscadmin.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/parsetree.h"
+#include "parser/parse_expr.h"
 #include "pgstat.h"
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/resowner.h"
 #include "utils/timestamp.h"
 #include "utils/typcache.h"
 #include "utils/xml.h"
@@ -477,6 +486,9 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		&&CASE_EEOP_GROUPING_FUNC,
 		&&CASE_EEOP_WINDOW_FUNC,
 		&&CASE_EEOP_SUBPLAN,
+		&&CASE_EEOP_JSON_CONSTRUCTOR,
+		&&CASE_EEOP_IS_JSON,
+		&&CASE_EEOP_JSONEXPR,
 		&&CASE_EEOP_AGG_STRICT_DESERIALIZE,
 		&&CASE_EEOP_AGG_DESERIALIZE,
 		&&CASE_EEOP_AGG_STRICT_INPUT_CHECK_ARGS,
@@ -1786,7 +1798,27 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull)
 		{
 			/* too complex for an inline implementation */
 			ExecEvalAggOrderedTransTuple(state, op, econtext);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSON_CONSTRUCTOR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonConstructor(state, op, econtext);
+			EEO_NEXT();
+		}
 
+		EEO_CASE(EEOP_IS_JSON)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJsonIsPredicate(state, op);
+			EEO_NEXT();
+		}
+
+		EEO_CASE(EEOP_JSONEXPR)
+		{
+			/* too complex for an inline implementation */
+			ExecEvalJson(state, op, econtext);
 			EEO_NEXT();
 		}
 
@@ -3900,6 +3932,91 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 	}
 }
 
+void
+ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op)
+{
+	JsonIsPredicate *pred = op->d.is_json.pred;
+	Datum		js = *op->resvalue;
+	Oid			exprtype;
+	bool		res;
+
+	if (*op->resnull)
+	{
+		*op->resvalue = BoolGetDatum(false);
+		return;
+	}
+
+	exprtype = exprType(pred->expr);
+
+	if (exprtype == TEXTOID || exprtype == JSONOID)
+	{
+		text	   *json = DatumGetTextP(js);
+
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			switch (json_get_first_token(json, false))
+			{
+				case JSON_TOKEN_OBJECT_START:
+					res = pred->value_type == JS_TYPE_OBJECT;
+					break;
+				case JSON_TOKEN_ARRAY_START:
+					res = pred->value_type == JS_TYPE_ARRAY;
+					break;
+				case JSON_TOKEN_STRING:
+				case JSON_TOKEN_NUMBER:
+				case JSON_TOKEN_TRUE:
+				case JSON_TOKEN_FALSE:
+				case JSON_TOKEN_NULL:
+					res = pred->value_type == JS_TYPE_SCALAR;
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/*
+		 * Do full parsing pass only for uniqueness check or for
+		 * JSON text validation.
+		 */
+		if (res && (pred->unique_keys || exprtype == TEXTOID))
+			res = json_validate(json, pred->unique_keys, false);
+	}
+	else if (exprtype == JSONBOID)
+	{
+		if (pred->value_type == JS_TYPE_ANY)
+			res = true;
+		else
+		{
+			Jsonb	   *jb = DatumGetJsonbP(js);
+
+			switch (pred->value_type)
+			{
+				case JS_TYPE_OBJECT:
+					res = JB_ROOT_IS_OBJECT(jb);
+					break;
+				case JS_TYPE_ARRAY:
+					res = JB_ROOT_IS_ARRAY(jb) && !JB_ROOT_IS_SCALAR(jb);
+					break;
+				case JS_TYPE_SCALAR:
+					res = JB_ROOT_IS_ARRAY(jb) && JB_ROOT_IS_SCALAR(jb);
+					break;
+				default:
+					res = false;
+					break;
+			}
+		}
+
+		/* Key uniqueness check is redundant for jsonb */
+	}
+	else
+		res = false;
+
+	*op->resvalue = BoolGetDatum(res);
+}
+
 /*
  * ExecEvalGroupingFunc
  *
@@ -4380,3 +4497,612 @@ ExecAggPlainTransByRef(AggState *aggstate, AggStatePerTrans pertrans,
 
 	MemoryContextSwitchTo(oldContext);
 }
+
+/*
+ * Evaluate a JSON constructor expression.
+ */
+void
+ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+						ExprContext *econtext)
+{
+	Datum		res;
+	JsonConstructorExpr *ctor = op->d.json_constructor.constructor;
+	bool		is_jsonb = ctor->returning->format->format_type == JS_FORMAT_JSONB;
+	bool		isnull = false;
+
+	if (ctor->type == JSCTOR_JSON_ARRAY)
+		res = (is_jsonb ?
+			   jsonb_build_array_worker :
+			   json_build_array_worker)(op->d.json_constructor.nargs,
+										op->d.json_constructor.arg_values,
+										op->d.json_constructor.arg_nulls,
+										op->d.json_constructor.arg_types,
+										op->d.json_constructor.constructor->absent_on_null);
+	else if (ctor->type == JSCTOR_JSON_OBJECT)
+		res = (is_jsonb ?
+			   jsonb_build_object_worker :
+			   json_build_object_worker)(op->d.json_constructor.nargs,
+										 op->d.json_constructor.arg_values,
+										 op->d.json_constructor.arg_nulls,
+										 op->d.json_constructor.arg_types,
+										 op->d.json_constructor.constructor->absent_on_null,
+										 op->d.json_constructor.constructor->unique);
+	else if (ctor->type == JSCTOR_JSON_SCALAR)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			int			category = op->d.json_constructor.arg_type_cache[0].category;
+			Oid			outfuncid = op->d.json_constructor.arg_type_cache[0].outfuncid;
+
+			if (is_jsonb)
+				res = to_jsonb_worker(value, category, outfuncid);
+			else
+				res = to_json_worker(value, category, outfuncid);
+		}
+	}
+	else if (ctor->type == JSCTOR_JSON_PARSE)
+	{
+		if (op->d.json_constructor.arg_nulls[0])
+		{
+			res = (Datum) 0;
+			isnull = true;
+		}
+		else
+		{
+			Datum		value = op->d.json_constructor.arg_values[0];
+			text	   *js = DatumGetTextP(value);
+
+			if (is_jsonb)
+				res = jsonb_from_text(js, true);
+			else
+			{
+				(void) json_validate(js, true, true);
+				res = value;
+			}
+		}
+	}
+	else
+	{
+		res = (Datum) 0;
+		elog(ERROR, "invalid JsonConstructorExpr type %d", ctor->type);
+	}
+
+	*op->resvalue = res;
+	*op->resnull = isnull;
+}
+
+/*
+ * Evaluate a JSON error/empty behavior result.
+ */
+static Datum
+ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
+					 ExprState *default_estate, bool *is_null)
+{
+	*is_null = false;
+
+	switch (behavior->btype)
+	{
+		case JSON_BEHAVIOR_EMPTY_ARRAY:
+			return JsonbPGetDatum(JsonbMakeEmptyArray());
+
+		case JSON_BEHAVIOR_EMPTY_OBJECT:
+			return JsonbPGetDatum(JsonbMakeEmptyObject());
+
+		case JSON_BEHAVIOR_TRUE:
+			return BoolGetDatum(true);
+
+		case JSON_BEHAVIOR_FALSE:
+			return BoolGetDatum(false);
+
+		case JSON_BEHAVIOR_NULL:
+		case JSON_BEHAVIOR_UNKNOWN:
+			*is_null = true;
+			return (Datum) 0;
+
+		case JSON_BEHAVIOR_DEFAULT:
+			return ExecEvalExpr(default_estate, econtext, is_null);
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON behavior %d", behavior->btype);
+			return (Datum) 0;
+	}
+}
+
+/*
+ * Evaluate a coercion of a JSON item to the target type.
+ */
+static Datum
+ExecEvalJsonExprCoercion(ExprEvalStep *op, ExprContext *econtext,
+						 Datum res, bool *isNull, void *p, bool *error)
+{
+	ExprState *estate = p;
+
+	if (estate)		/* coerce using specified expression */
+		return ExecEvalExpr(estate, econtext, isNull);
+
+	if (op->d.jsonexpr.jsexpr->op != IS_JSON_EXISTS)
+	{
+		JsonCoercion *coercion = op->d.jsonexpr.jsexpr->result_coercion;
+		JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+		Jsonb	   *jb = *isNull ? NULL : DatumGetJsonbP(res);
+
+		if ((coercion && coercion->via_io) ||
+			(jexpr->omit_quotes && !*isNull &&
+			 JB_ROOT_IS_SCALAR(jb)))
+		{
+			/* strip quotes and call typinput function */
+			char	   *str = *isNull ? NULL : JsonbUnquote(jb);
+
+			return InputFunctionCall(&op->d.jsonexpr.input.func, str,
+									 op->d.jsonexpr.input.typioparam,
+									 jexpr->returning->typmod);
+		}
+		else if (coercion && coercion->via_populate)
+			return json_populate_type(res, JSONBOID,
+									  jexpr->returning->typid,
+									  jexpr->returning->typmod,
+									  &op->d.jsonexpr.cache,
+									  econtext->ecxt_per_query_memory,
+									  isNull);
+	}
+
+	if (op->d.jsonexpr.result_expr)
+	{
+		op->d.jsonexpr.res_expr->value = res;
+		op->d.jsonexpr.res_expr->isnull = *isNull;
+
+		res = ExecEvalExpr(op->d.jsonexpr.result_expr, econtext, isNull);
+	}
+
+	return res;
+}
+
+/*
+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
+				JsonbValue *val, JsonbValue *baseObject)
+{
+	JsonPathVariableEvalContext *var = NULL;
+	List	   *vars = cxt;
+	ListCell   *lc;
+	int			id = 1;
+
+	if (!varName)
+		return list_length(vars);
+
+	foreach(lc, vars)
+	{
+		var = lfirst(lc);
+
+		if (!strncmp(var->name, varName, varNameLen))
+			break;
+
+		var = NULL;
+		id++;
+	}
+
+	if (!var)
+		return -1;
+
+	if (!var->evaluated)
+	{
+		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
+		var->evaluated = true;
+	}
+
+	if (var->isnull)
+	{
+		val->type = jbvNull;
+		return 0;
+	}
+
+	JsonItemFromDatum(var->value, var->typid, var->typmod, val);
+
+	*baseObject = *val;
+	return id;
+}
+
+/*
+ * Prepare SQL/JSON item coercion to the output type. Returns a datum of the
+ * corresponding SQL type and a pointer to the coercion state.
+ */
+Datum
+ExecPrepareJsonItemCoercion(JsonbValue *item,
+							JsonReturning *returning,
+							struct JsonCoercionsState *coercions,
+							struct JsonCoercionState **pcoercion)
+{
+	struct JsonCoercionState *coercion;
+	Datum		res;
+	JsonbValue	buf;
+
+	if (item->type == jbvBinary &&
+		JsonContainerIsScalar(item->val.binary.data))
+	{
+		bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+		res = JsonbExtractScalar(item->val.binary.data, &buf);
+		item = &buf;
+		Assert(res);
+	}
+
+	/* get coercion state reference and datum of the corresponding SQL type */
+	switch (item->type)
+	{
+		case jbvNull:
+			coercion = &coercions->null;
+			res = (Datum) 0;
+			break;
+
+		case jbvString:
+			coercion = &coercions->string;
+			res = PointerGetDatum(
+				cstring_to_text_with_len(item->val.string.val,
+										 item->val.string.len));
+			break;
+
+		case jbvNumeric:
+			coercion = &coercions->numeric;
+			res = NumericGetDatum(item->val.numeric);
+			break;
+
+		case jbvBool:
+			coercion = &coercions->boolean;
+			res = BoolGetDatum(item->val.boolean);
+			break;
+
+		case jbvDatetime:
+			res = item->val.datetime.value;
+			switch (item->val.datetime.typid)
+			{
+				case DATEOID:
+					coercion = &coercions->date;
+					break;
+				case TIMEOID:
+					coercion = &coercions->time;
+					break;
+				case TIMETZOID:
+					coercion = &coercions->timetz;
+					break;
+				case TIMESTAMPOID:
+					coercion = &coercions->timestamp;
+					break;
+				case TIMESTAMPTZOID:
+					coercion = &coercions->timestamptz;
+					break;
+				default:
+					elog(ERROR, "unexpected jsonb datetime type oid %d",
+						 item->val.datetime.typid);
+					return (Datum) 0;
+			}
+			break;
+
+		case jbvArray:
+		case jbvObject:
+		case jbvBinary:
+			coercion = &coercions->composite;
+			res = JsonbPGetDatum(JsonbValueToJsonb(item));
+			break;
+
+		default:
+			elog(ERROR, "unexpected jsonb value type %d", item->type);
+			return (Datum) 0;
+	}
+
+	*pcoercion = coercion;
+
+	return res;
+}
+
+typedef Datum (*JsonFunc)(ExprEvalStep *op, ExprContext *econtext,
+						  Datum item, bool *resnull, void *p, bool *error);
+
+static Datum
+ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
+						 ExprContext *econtext,
+						 Datum res, bool *resnull,
+						 void *p, bool *error, bool subtrans)
+{
+	MemoryContext oldcontext;
+	ResourceOwner oldowner;
+
+	if (!subtrans)
+		/* No need to use subtransactions. */
+		return func(op, econtext, res, resnull, p, error);
+
+	/*
+	 * We should catch exceptions of category ERRCODE_DATA_EXCEPTION
+	 * and execute the corresponding ON ERROR behavior then.
+	 */
+	oldcontext = CurrentMemoryContext;
+	oldowner = CurrentResourceOwner;
+
+	Assert(error);
+
+	BeginInternalSubTransaction(NULL);
+	/* Want to execute expressions inside function's memory context */
+	MemoryContextSwitchTo(oldcontext);
+
+	PG_TRY();
+	{
+		res = func(op, econtext, res, resnull, p, error);
+
+		/* Commit the inner transaction, return to outer xact context */
+		ReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info in oldcontext */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Abort the inner transaction */
+		RollbackAndReleaseCurrentSubTransaction();
+		MemoryContextSwitchTo(oldcontext);
+		CurrentResourceOwner = oldowner;
+
+		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
+			ERRCODE_DATA_EXCEPTION)
+			ReThrowError(edata);
+
+		res = (Datum) 0;
+		*error = true;
+	}
+	PG_END_TRY();
+
+	return res;
+}
+
+
+typedef struct
+{
+	JsonPath   *path;
+	bool	   *error;
+	bool		coercionInSubtrans;
+} ExecEvalJsonExprContext;
+
+static Datum
+ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
+				 Datum item, bool *resnull, void *pcxt,
+				 bool *error)
+{
+	ExecEvalJsonExprContext *cxt = pcxt;
+	JsonPath   *path = cxt->path;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	ExprState  *estate = NULL;
+	bool		empty = false;
+	Datum		res = (Datum) 0;
+
+	switch (jexpr->op)
+	{
+		case IS_JSON_QUERY:
+			res = JsonPathQuery(item, path, jexpr->wrapper, &empty, error,
+								op->d.jsonexpr.args);
+			if (error && *error)
+			{
+				*resnull = true;
+				return (Datum) 0;
+			}
+			*resnull = !DatumGetPointer(res);
+			break;
+
+		case IS_JSON_VALUE:
+			{
+				struct JsonCoercionState *jcstate;
+				JsonbValue *jbv = JsonPathValue(item, path, &empty, error,
+												op->d.jsonexpr.args);
+
+				if (error && *error)
+					return (Datum) 0;
+
+				if (!jbv)	/* NULL or empty */
+					break;
+
+				Assert(!empty);
+
+				*resnull = false;
+
+				/* coerce scalar item to the output type */
+				if (jexpr->returning->typid == JSONOID ||
+					jexpr->returning->typid == JSONBOID)
+				{
+					/* Use result coercion from json[b] to the output type */
+					res = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+					break;
+				}
+
+				/* Use coercion from SQL/JSON item type to the output type */
+				res = ExecPrepareJsonItemCoercion(jbv,
+												  op->d.jsonexpr.jsexpr->returning,
+												  &op->d.jsonexpr.coercions,
+												  &jcstate);
+
+				if (jcstate->coercion &&
+					(jcstate->coercion->via_io ||
+					 jcstate->coercion->via_populate))
+				{
+					if (error)
+					{
+						*error = true;
+						return (Datum) 0;
+					}
+					/*
+					 * Coercion via I/O means here that the cast to the target
+					 * type simply does not exist.
+					 */
+					ereport(ERROR,
+							/*
+							 * XXX Standard says about a separate error code
+							 * ERRCODE_SQL_JSON_ITEM_CANNOT_BE_CAST_TO_TARGET_TYPE
+							 * but does not define its number.
+							 */
+							(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+							 errmsg("SQL/JSON item cannot be cast to target type")));
+				}
+				else if (!jcstate->estate)
+					return res;		/* no coercion */
+
+				/* coerce using specific expression */
+				estate = jcstate->estate;
+				op->d.jsonexpr.coercion_expr->value = res;
+				op->d.jsonexpr.coercion_expr->isnull = *resnull;
+				break;
+			}
+
+		case IS_JSON_EXISTS:
+			{
+				bool		exists = JsonPathExists(item, path,
+													op->d.jsonexpr.args,
+													error);
+
+				*resnull = error && *error;
+				res = BoolGetDatum(exists);
+
+				if (!op->d.jsonexpr.result_expr)
+					return res;
+
+				/* coerce using result expression */
+				estate = op->d.jsonexpr.result_expr;
+				op->d.jsonexpr.res_expr->value = res;
+				op->d.jsonexpr.res_expr->isnull = *resnull;
+				break;
+			}
+
+		default:
+			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
+			return (Datum) 0;
+	}
+
+	if (empty)
+	{
+		Assert(jexpr->on_empty);	/* it is not JSON_EXISTS */
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_ERROR)
+		{
+			if (error)
+			{
+				*error = true;
+				return (Datum) 0;
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_NO_SQL_JSON_ITEM),
+					 errmsg("no SQL/JSON item")));
+		}
+
+		if (jexpr->on_empty->btype == JSON_BEHAVIOR_DEFAULT)
+			/*
+			 * Execute DEFAULT expression as a coercion expression, because
+			 * its result is already coerced to the target type.
+			 */
+			estate = op->d.jsonexpr.default_on_empty;
+		else
+			/* Execute ON EMPTY behavior */
+			res = ExecEvalJsonBehavior(econtext, jexpr->on_empty,
+									   op->d.jsonexpr.default_on_empty,
+									   resnull);
+	}
+
+	return ExecEvalJsonExprSubtrans(ExecEvalJsonExprCoercion, op, econtext,
+									res, resnull, estate, error,
+									cxt->coercionInSubtrans);
+}
+
+bool
+ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+								struct JsonCoercionsState *coercions)
+{
+	if (jsexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+		return false;
+
+	if (jsexpr->op == IS_JSON_EXISTS && !jsexpr->result_coercion)
+		return false;
+
+	if (!coercions)
+		return true;
+
+	return false;
+}
+
+/* ----------------------------------------------------------------
+ *		ExecEvalJson
+ * ----------------------------------------------------------------
+ */
+void
+ExecEvalJson(ExprState *state, ExprEvalStep *op, ExprContext *econtext)
+{
+	ExecEvalJsonExprContext cxt;
+	JsonExpr   *jexpr = op->d.jsonexpr.jsexpr;
+	Datum		item;
+	Datum		res = (Datum) 0;
+	JsonPath   *path;
+	ListCell   *lc;
+	bool		error = false;
+	bool		needSubtrans;
+	bool		throwErrors = jexpr->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	*op->resnull = true;		/* until we get a result */
+	*op->resvalue = (Datum) 0;
+
+	if (op->d.jsonexpr.formatted_expr->isnull || op->d.jsonexpr.pathspec->isnull)
+	{
+		/* execute domain checks for NULLs */
+		(void) ExecEvalJsonExprCoercion(op, econtext, res, op->resnull,
+										NULL, NULL);
+
+		Assert(*op->resnull);
+		return;
+	}
+
+	item = op->d.jsonexpr.formatted_expr->value;
+	path = DatumGetJsonPathP(op->d.jsonexpr.pathspec->value);
+
+	/* reset JSON path variable contexts */
+	foreach(lc, op->d.jsonexpr.args)
+	{
+		JsonPathVariableEvalContext *var = lfirst(lc);
+
+		var->econtext = econtext;
+		var->evaluated = false;
+	}
+
+	needSubtrans = ExecEvalJsonNeedsSubTransaction(jexpr, &op->d.jsonexpr.coercions);
+
+	cxt.path = path;
+	cxt.error = throwErrors ? NULL : &error;
+	cxt.coercionInSubtrans = !needSubtrans && !throwErrors;
+	Assert(!needSubtrans || cxt.error);
+
+	res = ExecEvalJsonExprSubtrans(ExecEvalJsonExpr, op, econtext, item,
+								   op->resnull, &cxt, cxt.error,
+								   needSubtrans);
+
+	if (error)
+	{
+		/* Execute ON ERROR behavior */
+		res = ExecEvalJsonBehavior(econtext, jexpr->on_error,
+								   op->d.jsonexpr.default_on_error,
+								   op->resnull);
+
+		/* result is already coerced in DEFAULT behavior case */
+		if (jexpr->on_error->btype != JSON_BEHAVIOR_DEFAULT)
+			res = ExecEvalJsonExprCoercion(op, econtext, res,
+										   op->resnull,
+										   NULL, NULL);
+	}
+
+	*op->resvalue = res;
+}
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index bd86f546d7..9c8f341d96 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2348,6 +2348,24 @@ llvm_compile_expr(ExprState *state)
 				LLVMBuildBr(b, opblocks[opno + 1]);
 				break;
 
+			case EEOP_JSON_CONSTRUCTOR:
+				build_EvalXFunc(b, mod, "ExecEvalJsonConstructor",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_IS_JSON:
+				build_EvalXFunc(b, mod, "ExecEvalJsonIsPredicate",
+								v_state, op);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
+			case EEOP_JSONEXPR:
+				build_EvalXFunc(b, mod, "ExecEvalJson",
+								v_state, op, v_econtext);
+				LLVMBuildBr(b, opblocks[opno + 1]);
+				break;
+
 			case EEOP_LAST:
 				Assert(false);
 				break;
diff --git a/src/backend/jit/llvm/llvmjit_types.c b/src/backend/jit/llvm/llvmjit_types.c
index d5191cf02b..b2bda86889 100644
--- a/src/backend/jit/llvm/llvmjit_types.c
+++ b/src/backend/jit/llvm/llvmjit_types.c
@@ -131,6 +131,9 @@ void	   *referenced_functions[] =
 	ExecEvalSysVar,
 	ExecEvalWholeRowVar,
 	ExecEvalXmlExpr,
+	ExecEvalJsonConstructor,
+	ExecEvalJsonIsPredicate,
+	ExecEvalJson,
 	MakeExpandedObjectReadOnlyInternal,
 	slot_getmissingattrs,
 	slot_getsomeattrs_int,
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 55f720a88f..a791ebd6cd 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2298,6 +2298,390 @@ _copyOnConflictExpr(const OnConflictExpr *from)
 	return newnode;
 }
 
+
+/*
+ * _copyJsonFormat
+ */
+static JsonFormat *
+_copyJsonFormat(const JsonFormat *from)
+{
+	JsonFormat *newnode = makeNode(JsonFormat);
+
+	COPY_SCALAR_FIELD(format_type);
+	COPY_SCALAR_FIELD(encoding);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonReturning
+ */
+static JsonReturning *
+_copyJsonReturning(const JsonReturning *from)
+{
+	JsonReturning *newnode = makeNode(JsonReturning);
+
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(typid);
+	COPY_SCALAR_FIELD(typmod);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonValueExpr
+ */
+static JsonValueExpr *
+_copyJsonValueExpr(const JsonValueExpr *from)
+{
+	JsonValueExpr  *newnode = makeNode(JsonValueExpr);
+
+	COPY_NODE_FIELD(raw_expr);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(format);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonParseExpr
+ */
+static JsonParseExpr *
+_copyJsonParseExpr(const JsonParseExpr *from)
+{
+	JsonParseExpr  *newnode = makeNode(JsonParseExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonScalarExpr
+ */
+static JsonScalarExpr *
+_copyJsonScalarExpr(const JsonScalarExpr *from)
+{
+	JsonScalarExpr *newnode = makeNode(JsonScalarExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonSerializeExpr
+ */
+static JsonSerializeExpr *
+_copyJsonSerializeExpr(const JsonSerializeExpr *from)
+{
+	JsonSerializeExpr *newnode = makeNode(JsonSerializeExpr);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(output);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_copyJsonConstructorExpr(const JsonConstructorExpr *from)
+{
+	JsonConstructorExpr *newnode = makeNode(JsonConstructorExpr);
+
+	COPY_SCALAR_FIELD(type);
+	COPY_NODE_FIELD(args);
+	COPY_NODE_FIELD(func);
+	COPY_NODE_FIELD(coercion);
+	COPY_NODE_FIELD(returning);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonKeyValue
+ */
+static JsonKeyValue *
+_copyJsonKeyValue(const JsonKeyValue *from)
+{
+	JsonKeyValue *newnode = makeNode(JsonKeyValue);
+
+	COPY_NODE_FIELD(key);
+	COPY_NODE_FIELD(value);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectConstructor
+ */
+static JsonObjectConstructor *
+_copyJsonObjectConstructor(const JsonObjectConstructor *from)
+{
+	JsonObjectConstructor *newnode = makeNode(JsonObjectConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonAggConstructor
+ */
+static JsonAggConstructor *
+_copyJsonAggConstructor(const JsonAggConstructor *from)
+{
+	JsonAggConstructor *newnode = makeNode(JsonAggConstructor);
+
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(agg_filter);
+	COPY_NODE_FIELD(agg_order);
+	COPY_NODE_FIELD(over);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonObjectAgg
+ */
+static JsonObjectAgg *
+_copyJsonObjectAgg(const JsonObjectAgg *from)
+{
+	JsonObjectAgg *newnode = makeNode(JsonObjectAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_SCALAR_FIELD(unique);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonOutput
+ */
+static JsonOutput *
+_copyJsonOutput(const JsonOutput *from)
+{
+	JsonOutput	   *newnode = makeNode(JsonOutput);
+
+	COPY_NODE_FIELD(typeName);
+	COPY_NODE_FIELD(returning);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayConstructor
+ */
+static JsonArrayConstructor *
+_copyJsonArrayConstructor(const JsonArrayConstructor *from)
+{
+	JsonArrayConstructor *newnode = makeNode(JsonArrayConstructor);
+
+	COPY_NODE_FIELD(exprs);
+	COPY_NODE_FIELD(output);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayAgg
+ */
+static JsonArrayAgg *
+_copyJsonArrayAgg(const JsonArrayAgg *from)
+{
+	JsonArrayAgg *newnode = makeNode(JsonArrayAgg);
+
+	COPY_NODE_FIELD(constructor);
+	COPY_NODE_FIELD(arg);
+	COPY_SCALAR_FIELD(absent_on_null);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArrayQueryConstructor
+ */
+static JsonArrayQueryConstructor *
+_copyJsonArrayQueryConstructor(const JsonArrayQueryConstructor *from)
+{
+	JsonArrayQueryConstructor *newnode = makeNode(JsonArrayQueryConstructor);
+
+	COPY_NODE_FIELD(query);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(format);
+	COPY_SCALAR_FIELD(absent_on_null);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonExpr
+ */
+static JsonExpr *
+_copyJsonExpr(const JsonExpr *from)
+{
+	JsonExpr    *newnode = makeNode(JsonExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(formatted_expr);
+	COPY_NODE_FIELD(result_coercion);
+	COPY_NODE_FIELD(format);
+	COPY_NODE_FIELD(path_spec);
+	COPY_NODE_FIELD(passing_values);
+	COPY_NODE_FIELD(passing_names);
+	COPY_NODE_FIELD(returning);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(coercions);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCoercion
+ */
+static JsonCoercion *
+_copyJsonCoercion(const JsonCoercion *from)
+{
+	JsonCoercion *newnode = makeNode(JsonCoercion);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(via_populate);
+	COPY_SCALAR_FIELD(via_io);
+	COPY_SCALAR_FIELD(collation);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonItemCoercions
+ */
+static JsonItemCoercions *
+_copyJsonItemCoercions(const JsonItemCoercions *from)
+{
+	JsonItemCoercions *newnode = makeNode(JsonItemCoercions);
+
+	COPY_NODE_FIELD(null);
+	COPY_NODE_FIELD(string);
+	COPY_NODE_FIELD(numeric);
+	COPY_NODE_FIELD(boolean);
+	COPY_NODE_FIELD(date);
+	COPY_NODE_FIELD(time);
+	COPY_NODE_FIELD(timetz);
+	COPY_NODE_FIELD(timestamp);
+	COPY_NODE_FIELD(timestamptz);
+	COPY_NODE_FIELD(composite);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonFuncExpr
+ */
+static JsonFuncExpr *
+_copyJsonFuncExpr(const JsonFuncExpr *from)
+{
+	JsonFuncExpr   *newnode = makeNode(JsonFuncExpr);
+
+	COPY_SCALAR_FIELD(op);
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(output);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonIsPredicate
+ */
+static JsonIsPredicate *
+_copyJsonIsPredicate(const JsonIsPredicate *from)
+{
+	JsonIsPredicate *newnode = makeNode(JsonIsPredicate);
+
+	COPY_NODE_FIELD(expr);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(value_type);
+	COPY_SCALAR_FIELD(unique_keys);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonBehavior
+ */
+static JsonBehavior *
+_copyJsonBehavior(const JsonBehavior *from)
+{
+	JsonBehavior   *newnode = makeNode(JsonBehavior);
+
+	COPY_SCALAR_FIELD(btype);
+	COPY_NODE_FIELD(default_expr);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonCommon
+ */
+static JsonCommon *
+_copyJsonCommon(const JsonCommon *from)
+{
+	JsonCommon	   *newnode = makeNode(JsonCommon);
+
+	COPY_NODE_FIELD(expr);
+	COPY_NODE_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(passing);
+	COPY_LOCATION_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonArgument
+ */
+static JsonArgument *
+_copyJsonArgument(const JsonArgument *from)
+{
+	JsonArgument   *newnode = makeNode(JsonArgument);
+
+	COPY_NODE_FIELD(val);
+	COPY_STRING_FIELD(name);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5350,6 +5734,75 @@ copyObjectImpl(const void *from)
 		case T_OnConflictExpr:
 			retval = _copyOnConflictExpr(from);
 			break;
+		case T_JsonFormat:
+			retval = _copyJsonFormat(from);
+			break;
+		case T_JsonReturning:
+			retval = _copyJsonReturning(from);
+			break;
+		case T_JsonValueExpr:
+			retval = _copyJsonValueExpr(from);
+			break;
+		case T_JsonParseExpr:
+			retval = _copyJsonParseExpr(from);
+			break;
+		case T_JsonScalarExpr:
+			retval = _copyJsonScalarExpr(from);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _copyJsonSerializeExpr(from);
+			break;
+		case T_JsonKeyValue:
+			retval = _copyJsonKeyValue(from);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _copyJsonConstructorExpr(from);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _copyJsonObjectConstructor(from);
+			break;
+		case T_JsonAggConstructor:
+			retval = _copyJsonAggConstructor(from);
+			break;
+		case T_JsonObjectAgg:
+			retval = _copyJsonObjectAgg(from);
+			break;
+		case T_JsonOutput:
+			retval = _copyJsonOutput(from);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _copyJsonArrayConstructor(from);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _copyJsonArrayQueryConstructor(from);
+			break;
+		case T_JsonArrayAgg:
+			retval = _copyJsonArrayAgg(from);
+			break;
+		case T_JsonIsPredicate:
+			retval = _copyJsonIsPredicate(from);
+			break;
+		case T_JsonFuncExpr:
+			retval = _copyJsonFuncExpr(from);
+			break;
+		case T_JsonExpr:
+			retval = _copyJsonExpr(from);
+			break;
+		case T_JsonCommon:
+			retval = _copyJsonCommon(from);
+			break;
+		case T_JsonBehavior:
+			retval = _copyJsonBehavior(from);
+			break;
+		case T_JsonArgument:
+			retval = _copyJsonArgument(from);
+			break;
+		case T_JsonCoercion:
+			retval = _copyJsonCoercion(from);
+			break;
+		case T_JsonItemCoercions:
+			retval = _copyJsonItemCoercions(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 82562eb9b8..c52cadb5d9 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -841,6 +841,290 @@ _equalOnConflictExpr(const OnConflictExpr *a, const OnConflictExpr *b)
 	return true;
 }
 
+static bool
+_equalJsonFormat(const JsonFormat *a, const JsonFormat *b)
+{
+	COMPARE_SCALAR_FIELD(format_type);
+	COMPARE_SCALAR_FIELD(encoding);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonReturning(const JsonReturning *a, const JsonReturning *b)
+{
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(typid);
+	COMPARE_SCALAR_FIELD(typmod);
+
+	return true;
+}
+
+static bool
+_equalJsonValueExpr(const JsonValueExpr *a, const JsonValueExpr *b)
+{
+	COMPARE_NODE_FIELD(raw_expr);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(format);
+
+	return true;
+}
+
+static bool
+_equalJsonParseExpr(const JsonParseExpr *a, const JsonParseExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonScalarExpr(const JsonScalarExpr *a, const JsonScalarExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonSerializeExpr(const JsonSerializeExpr *a, const JsonSerializeExpr *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonConstructorExpr(const JsonConstructorExpr *a, const JsonConstructorExpr *b)
+{
+	COMPARE_SCALAR_FIELD(type);
+	COMPARE_NODE_FIELD(args);
+	COMPARE_NODE_FIELD(func);
+	COMPARE_NODE_FIELD(coercion);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonKeyValue(const JsonKeyValue *a, const JsonKeyValue *b)
+{
+	COMPARE_NODE_FIELD(key);
+	COMPARE_NODE_FIELD(value);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectConstructor(const JsonObjectConstructor *a,
+							const JsonObjectConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonAggConstructor(const JsonAggConstructor *a,
+						 const JsonAggConstructor *b)
+{
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(agg_filter);
+	COMPARE_NODE_FIELD(agg_order);
+	COMPARE_NODE_FIELD(over);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonObjectAgg(const JsonObjectAgg *a, const JsonObjectAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_SCALAR_FIELD(unique);
+
+	return true;
+}
+
+static bool
+_equalJsonOutput(const JsonOutput *a, const JsonOutput *b)
+{
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_NODE_FIELD(returning);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayConstructor(const JsonArrayConstructor *a,
+						   const JsonArrayConstructor *b)
+{
+	COMPARE_NODE_FIELD(exprs);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayAgg(const JsonArrayAgg *a, const JsonArrayAgg *b)
+{
+	COMPARE_NODE_FIELD(constructor);
+	COMPARE_NODE_FIELD(arg);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+
+	return true;
+}
+
+static bool
+_equalJsonArrayQueryConstructor(const JsonArrayQueryConstructor *a,
+								const JsonArrayQueryConstructor *b)
+{
+	COMPARE_NODE_FIELD(query);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_SCALAR_FIELD(absent_on_null);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonFuncExpr(const JsonFuncExpr *a, const JsonFuncExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(common);
+	COMPARE_NODE_FIELD(output);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonCommon(const JsonCommon *a, const JsonCommon *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_NODE_FIELD(pathspec);
+	COMPARE_STRING_FIELD(pathname);
+	COMPARE_NODE_FIELD(passing);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonArgument(const JsonArgument *a, const JsonArgument *b)
+{
+	COMPARE_NODE_FIELD(val);
+	COMPARE_STRING_FIELD(name);
+
+	return true;
+}
+
+static bool
+_equalJsonIsPredicate(const JsonIsPredicate *a,
+					  const JsonIsPredicate *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(value_type);
+	COMPARE_SCALAR_FIELD(unique_keys);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonBehavior
+ */
+static bool
+_equalJsonBehavior(const JsonBehavior *a, const JsonBehavior *b)
+{
+	COMPARE_SCALAR_FIELD(btype);
+	COMPARE_NODE_FIELD(default_expr);
+
+	return true;
+}
+
+/*
+ * _equalJsonExpr
+ */
+static bool
+_equalJsonExpr(const JsonExpr *a, const JsonExpr *b)
+{
+	COMPARE_SCALAR_FIELD(op);
+	COMPARE_NODE_FIELD(formatted_expr);
+	COMPARE_NODE_FIELD(result_coercion);
+	COMPARE_NODE_FIELD(format);
+	COMPARE_NODE_FIELD(path_spec);
+	COMPARE_NODE_FIELD(passing_values);
+	COMPARE_NODE_FIELD(passing_names);
+	COMPARE_NODE_FIELD(returning);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(coercions);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_LOCATION_FIELD(location);
+
+	return true;
+}
+
+/*
+ * _equalJsonCoercion
+ */
+static bool
+_equalJsonCoercion(const JsonCoercion *a, const JsonCoercion *b)
+{
+	COMPARE_NODE_FIELD(expr);
+	COMPARE_SCALAR_FIELD(via_populate);
+	COMPARE_SCALAR_FIELD(via_io);
+	COMPARE_SCALAR_FIELD(collation);
+
+	return true;
+}
+
+/*
+ * _equalJsonItemCoercions
+ */
+static bool
+_equalJsonItemCoercions(const JsonItemCoercions *a, const JsonItemCoercions *b)
+{
+	COMPARE_NODE_FIELD(null);
+	COMPARE_NODE_FIELD(string);
+	COMPARE_NODE_FIELD(numeric);
+	COMPARE_NODE_FIELD(boolean);
+	COMPARE_NODE_FIELD(date);
+	COMPARE_NODE_FIELD(time);
+	COMPARE_NODE_FIELD(timetz);
+	COMPARE_NODE_FIELD(timestamp);
+	COMPARE_NODE_FIELD(timestamptz);
+	COMPARE_NODE_FIELD(composite);
+
+	return true;
+}
+
 /*
  * Stuff from pathnodes.h
  */
@@ -3358,6 +3642,42 @@ equal(const void *a, const void *b)
 		case T_JoinExpr:
 			retval = _equalJoinExpr(a, b);
 			break;
+		case T_JsonFormat:
+			retval = _equalJsonFormat(a, b);
+			break;
+		case T_JsonReturning:
+			retval = _equalJsonReturning(a, b);
+			break;
+		case T_JsonValueExpr:
+			retval = _equalJsonValueExpr(a, b);
+			break;
+		case T_JsonParseExpr:
+			retval = _equalJsonParseExpr(a, b);
+			break;
+		case T_JsonScalarExpr:
+			retval = _equalJsonScalarExpr(a, b);
+			break;
+		case T_JsonSerializeExpr:
+			retval = _equalJsonSerializeExpr(a, b);
+			break;
+		case T_JsonConstructorExpr:
+			retval = _equalJsonConstructorExpr(a, b);
+			break;
+		case T_JsonIsPredicate:
+			retval = _equalJsonIsPredicate(a, b);
+			break;
+		case T_JsonBehavior:
+			retval = _equalJsonBehavior(a, b);
+			break;
+		case T_JsonExpr:
+			retval = _equalJsonExpr(a, b);
+			break;
+		case T_JsonCoercion:
+			retval = _equalJsonCoercion(a, b);
+			break;
+		case T_JsonItemCoercions:
+			retval = _equalJsonItemCoercions(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -3938,6 +4258,39 @@ equal(const void *a, const void *b)
 		case T_PublicationTable:
 			retval = _equalPublicationTable(a, b);
 			break;
+		case T_JsonKeyValue:
+			retval = _equalJsonKeyValue(a, b);
+			break;
+		case T_JsonObjectConstructor:
+			retval = _equalJsonObjectConstructor(a, b);
+			break;
+		case T_JsonAggConstructor:
+			retval = _equalJsonAggConstructor(a, b);
+			break;
+		case T_JsonObjectAgg:
+			retval = _equalJsonObjectAgg(a, b);
+			break;
+		case T_JsonOutput:
+			retval = _equalJsonOutput(a, b);
+			break;
+		case T_JsonArrayConstructor:
+			retval = _equalJsonArrayConstructor(a, b);
+			break;
+		case T_JsonArrayQueryConstructor:
+			retval = _equalJsonArrayQueryConstructor(a, b);
+			break;
+		case T_JsonArrayAgg:
+			retval = _equalJsonArrayAgg(a, b);
+			break;
+		case T_JsonFuncExpr:
+			retval = _equalJsonFuncExpr(a, b);
+			break;
+		case T_JsonCommon:
+			retval = _equalJsonCommon(a, b);
+			break;
+		case T_JsonArgument:
+			retval = _equalJsonArgument(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index c85d8fe975..cd6c300e7b 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -19,6 +19,7 @@
 #include "catalog/pg_type.h"
 #include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "utils/errcodes.h"
 #include "utils/lsyscache.h"
 
 
@@ -818,3 +819,105 @@ makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols)
 	v->va_cols = va_cols;
 	return v;
 }
+
+/*
+ * makeJsonFormat -
+ *	  creates a JsonFormat node
+ */
+JsonFormat *
+makeJsonFormat(JsonFormatType type, JsonEncoding encoding, int location)
+{
+	JsonFormat *jf = makeNode(JsonFormat);
+
+	jf->format_type = type;
+	jf->encoding = encoding;
+	jf->location = location;
+
+	return jf;
+}
+
+/*
+ * makeJsonValueExpr -
+ *	  creates a JsonValueExpr node
+ */
+JsonValueExpr *
+makeJsonValueExpr(Expr *expr, JsonFormat *format)
+{
+	JsonValueExpr *jve = makeNode(JsonValueExpr);
+
+	jve->raw_expr = expr;
+	jve->formatted_expr = NULL;
+	jve->format = format;
+
+	return jve;
+}
+
+/*
+ * makeJsonBehavior -
+ *	  creates a JsonBehavior node
+ */
+JsonBehavior *
+makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
+{
+	JsonBehavior *behavior = makeNode(JsonBehavior);
+
+	behavior->btype = type;
+	behavior->default_expr = default_expr;
+
+	return behavior;
+}
+
+/*
+ * makeJsonEncoding -
+ *	  converts JSON encoding name to enum JsonEncoding
+ */
+JsonEncoding
+makeJsonEncoding(char *name)
+{
+	if (!pg_strcasecmp(name, "utf8"))
+		return JS_ENC_UTF8;
+	if (!pg_strcasecmp(name, "utf16"))
+		return JS_ENC_UTF16;
+	if (!pg_strcasecmp(name, "utf32"))
+		return JS_ENC_UTF32;
+
+	ereport(ERROR,
+			(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+			 errmsg("unrecognized JSON encoding: %s", name)));
+
+	return JS_ENC_DEFAULT;
+}
+
+/*
+ * makeJsonKeyValue -
+ *	  creates a JsonKeyValue node
+ */
+Node *
+makeJsonKeyValue(Node *key, Node *value)
+{
+	JsonKeyValue *n = makeNode(JsonKeyValue);
+
+	n->key = (Expr *) key;
+	n->value = castNode(JsonValueExpr, value);
+
+	return (Node *) n;
+}
+
+/*
+ * makeJsonIsPredicate -
+ *	  creates a JsonIsPredicate node
+ */
+Node *
+makeJsonIsPredicate(Node *expr, JsonFormat *format, JsonValueType value_type,
+					bool unique_keys, int location)
+{
+	JsonIsPredicate *n = makeNode(JsonIsPredicate);
+
+	n->expr = expr;
+	n->format = format;
+	n->value_type = value_type;
+	n->unique_keys = unique_keys;
+	n->location = location;
+
+	return (Node *) n;
+}
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ec25aae6e3..2fb2be2541 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -250,6 +250,25 @@ exprType(const Node *expr)
 		case T_PlaceHolderVar:
 			type = exprType((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			{
+				const JsonValueExpr *jve = (const JsonValueExpr *) expr;
+
+				type = exprType((Node *) (jve->formatted_expr ? jve->formatted_expr : jve->raw_expr));
+			}
+			break;
+		case T_JsonConstructorExpr:
+			type = ((const JsonConstructorExpr *) expr)->returning->typid;
+			break;
+		case T_JsonIsPredicate:
+			type = BOOLOID;
+			break;
+		case T_JsonExpr:
+			type = ((const JsonExpr *) expr)->returning->typid;
+			break;
+		case T_JsonCoercion:
+			type = exprType(((const JsonCoercion *) expr)->expr);
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			type = InvalidOid;	/* keep compiler quiet */
@@ -482,6 +501,14 @@ exprTypmod(const Node *expr)
 			return ((const SetToDefault *) expr)->typeMod;
 		case T_PlaceHolderVar:
 			return exprTypmod((Node *) ((const PlaceHolderVar *) expr)->phexpr);
+		case T_JsonValueExpr:
+			return exprTypmod((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+		case T_JsonConstructorExpr:
+			return ((const JsonConstructorExpr *) expr)->returning->typmod;
+		case T_JsonExpr:
+			return ((JsonExpr *) expr)->returning->typmod;
+		case T_JsonCoercion:
+			return exprTypmod(((const JsonCoercion *) expr)->expr);
 		default:
 			break;
 	}
@@ -958,6 +985,37 @@ exprCollation(const Node *expr)
 		case T_PlaceHolderVar:
 			coll = exprCollation((Node *) ((const PlaceHolderVar *) expr)->phexpr);
 			break;
+		case T_JsonValueExpr:
+			coll = exprCollation((Node *) ((const JsonValueExpr *) expr)->formatted_expr);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				const JsonConstructorExpr *ctor = (const JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					coll = exprCollation((Node *) ctor->coercion);
+				else
+					coll = InvalidOid;
+			}
+			break;
+		case T_JsonIsPredicate:
+			coll = InvalidOid;	/* result is always an boolean type */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					coll = InvalidOid;
+				else if (coercion->expr)
+					coll = exprCollation(coercion->expr);
+				else if (coercion->via_io || coercion->via_populate)
+					coll = coercion->collation;
+				else
+					coll = InvalidOid;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			coll = InvalidOid;	/* keep compiler quiet */
@@ -1170,6 +1228,38 @@ exprSetCollation(Node *expr, Oid collation)
 			/* NextValueExpr's result is an integer type ... */
 			Assert(!OidIsValid(collation)); /* ... so never set a collation */
 			break;
+		case T_JsonValueExpr:
+			exprSetCollation((Node *) ((JsonValueExpr *) expr)->formatted_expr,
+							 collation);
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) expr;
+
+				if (ctor->coercion)
+					exprSetCollation((Node *) ctor->coercion, collation);
+				else
+					Assert(!OidIsValid(collation)); /* result is always a json[b] type */
+			}
+			break;
+		case T_JsonIsPredicate:
+			Assert(!OidIsValid(collation)); /* result is always boolean */
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr *jexpr = (JsonExpr *) expr;
+				JsonCoercion *coercion = jexpr->result_coercion;
+
+				if (!coercion)
+					Assert(!OidIsValid(collation));
+				else if (coercion->expr)
+					exprSetCollation(coercion->expr, collation);
+				else if (coercion->via_io || coercion->via_populate)
+					coercion->collation = collation;
+				else
+					Assert(!OidIsValid(collation));
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
 			break;
@@ -1616,6 +1706,24 @@ exprLocation(const Node *expr)
 		case T_PartitionRangeDatum:
 			loc = ((const PartitionRangeDatum *) expr)->location;
 			break;
+		case T_JsonValueExpr:
+			loc = exprLocation((Node *) ((const JsonValueExpr *) expr)->raw_expr);
+			break;
+		case T_JsonConstructorExpr:
+			loc = ((const JsonConstructorExpr *) expr)->location;
+			break;
+		case T_JsonIsPredicate:
+			loc = ((const JsonIsPredicate *) expr)->location;
+			break;
+		case T_JsonExpr:
+			{
+				const JsonExpr *jsexpr = (const JsonExpr *) expr;
+
+				/* consider both function name and leftmost arg */
+				loc = leftmostLoc(jsexpr->location,
+								  exprLocation(jsexpr->formatted_expr));
+			}
+			break;
 		default:
 			/* for any other node type it's just unknown... */
 			loc = -1;
@@ -2350,6 +2458,78 @@ expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				if (walker(jexpr->formatted_expr, context))
+					return true;
+				if (walker(jexpr->result_coercion, context))
+					return true;
+				if (walker(jexpr->passing_values, context))
+					return true;
+				/* we assume walker doesn't care about passing_names */
+				if (jexpr->on_empty &&
+					walker(jexpr->on_empty->default_expr, context))
+					return true;
+				if (walker(jexpr->on_error->default_expr, context))
+					return true;
+				if (walker(jexpr->coercions, context))
+					return true;
+			}
+			break;
+		case T_JsonCoercion:
+			return walker(((JsonCoercion *) node)->expr, context);
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+
+				if (walker(coercions->null, context))
+					return true;
+				if (walker(coercions->string, context))
+					return true;
+				if (walker(coercions->numeric, context))
+					return true;
+				if (walker(coercions->boolean, context))
+					return true;
+				if (walker(coercions->date, context))
+					return true;
+				if (walker(coercions->time, context))
+					return true;
+				if (walker(coercions->timetz, context))
+					return true;
+				if (walker(coercions->timestamp, context))
+					return true;
+				if (walker(coercions->timestamptz, context))
+					return true;
+				if (walker(coercions->composite, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -2680,6 +2860,7 @@ expression_tree_mutator(Node *node,
 		case T_RangeTblRef:
 		case T_SortGroupClause:
 		case T_CTESearchClause:
+		case T_JsonFormat:
 			return (Node *) copyObject(node);
 		case T_WithCheckOption:
 			{
@@ -3311,6 +3492,101 @@ expression_tree_mutator(Node *node,
 				return (Node *) newnode;
 			}
 			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *jr = (JsonReturning *) node;
+				JsonReturning *newnode;
+
+				FLATCOPY(newnode, jr, JsonReturning);
+				MUTATE(newnode->format, jr->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				JsonValueExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonValueExpr);
+				MUTATE(newnode->raw_expr, jve->raw_expr, Expr *);
+				MUTATE(newnode->formatted_expr, jve->formatted_expr, Expr *);
+				MUTATE(newnode->format, jve->format, JsonFormat *);
+
+				return (Node *) newnode;
+			}
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *jve = (JsonConstructorExpr *) node;
+				JsonConstructorExpr *newnode;
+
+				FLATCOPY(newnode, jve, JsonConstructorExpr);
+				MUTATE(newnode->args, jve->args, List *);
+				MUTATE(newnode->func, jve->func, Expr *);
+				MUTATE(newnode->coercion, jve->coercion, Expr *);
+				MUTATE(newnode->returning, jve->returning, JsonReturning *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+				JsonIsPredicate *newnode;
+
+				FLATCOPY(newnode, pred, JsonIsPredicate);
+				MUTATE(newnode->expr, pred->expr, Node *);
+
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+				JsonExpr    *newnode;
+
+				FLATCOPY(newnode, jexpr, JsonExpr);
+				MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
+				MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
+				MUTATE(newnode->result_coercion, jexpr->result_coercion, JsonCoercion *);
+				MUTATE(newnode->passing_values, jexpr->passing_values, List *);
+				/* assume mutator does not care about passing_names */
+				if (newnode->on_empty)
+					MUTATE(newnode->on_empty->default_expr,
+						   jexpr->on_empty->default_expr, Node *);
+				MUTATE(newnode->on_error->default_expr,
+					   jexpr->on_error->default_expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonCoercion:
+			{
+				JsonCoercion *coercion = (JsonCoercion *) node;
+				JsonCoercion *newnode;
+
+				FLATCOPY(newnode, coercion, JsonCoercion);
+				MUTATE(newnode->expr, coercion->expr, Node *);
+				return (Node *) newnode;
+			}
+			break;
+		case T_JsonItemCoercions:
+			{
+				JsonItemCoercions *coercions = (JsonItemCoercions *) node;
+				JsonItemCoercions *newnode;
+
+				FLATCOPY(newnode, coercions, JsonItemCoercions);
+				MUTATE(newnode->null, coercions->null, JsonCoercion *);
+				MUTATE(newnode->string, coercions->string, JsonCoercion *);
+				MUTATE(newnode->numeric, coercions->numeric, JsonCoercion *);
+				MUTATE(newnode->boolean, coercions->boolean, JsonCoercion *);
+				MUTATE(newnode->date, coercions->date, JsonCoercion *);
+				MUTATE(newnode->time, coercions->time, JsonCoercion *);
+				MUTATE(newnode->timetz, coercions->timetz, JsonCoercion *);
+				MUTATE(newnode->timestamp, coercions->timestamp, JsonCoercion *);
+				MUTATE(newnode->timestamptz, coercions->timestamptz, JsonCoercion *);
+				MUTATE(newnode->composite, coercions->composite, JsonCoercion *);
+				return (Node *) newnode;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
@@ -3585,6 +3861,7 @@ raw_expression_tree_walker(Node *node,
 		case T_ParamRef:
 		case T_A_Const:
 		case T_A_Star:
+		case T_JsonFormat:
 			/* primitive node types with no subnodes */
 			break;
 		case T_Alias:
@@ -4019,6 +4296,187 @@ raw_expression_tree_walker(Node *node,
 		case T_CommonTableExpr:
 			/* search_clause and cycle_clause are not interesting here */
 			return walker(((CommonTableExpr *) node)->ctequery, context);
+		case T_JsonReturning:
+			return walker(((JsonReturning *) node)->format, context);
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				if (walker(jve->raw_expr, context))
+					return true;
+				if (walker(jve->formatted_expr, context))
+					return true;
+				if (walker(jve->format, context))
+					return true;
+			}
+			break;
+		case T_JsonParseExpr:
+			{
+				JsonParseExpr *jpe = (JsonParseExpr *) node;
+
+				if (walker(jpe->expr, context))
+					return true;
+				if (walker(jpe->output, context))
+					return true;
+			}
+			break;
+		case T_JsonScalarExpr:
+			{
+				JsonScalarExpr *jse = (JsonScalarExpr *) node;
+
+				if (walker(jse->expr, context))
+					return true;
+				if (walker(jse->output, context))
+					return true;
+			}
+			break;
+		case T_JsonSerializeExpr:
+			{
+				JsonSerializeExpr *jse = (JsonSerializeExpr *) node;
+
+				if (walker(jse->expr, context))
+					return true;
+				if (walker(jse->output, context))
+					return true;
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				if (walker(ctor->args, context))
+					return true;
+				if (walker(ctor->func, context))
+					return true;
+				if (walker(ctor->coercion, context))
+					return true;
+				if (walker(ctor->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonOutput:
+			{
+				JsonOutput *out = (JsonOutput *) node;
+
+				if (walker(out->typeName, context))
+					return true;
+				if (walker(out->returning, context))
+					return true;
+			}
+			break;
+		case T_JsonKeyValue:
+			{
+				JsonKeyValue *jkv = (JsonKeyValue *) node;
+
+				if (walker(jkv->key, context))
+					return true;
+				if (walker(jkv->value, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectConstructor:
+			{
+				JsonObjectConstructor *joc = (JsonObjectConstructor *) node;
+
+				if (walker(joc->output, context))
+					return true;
+				if (walker(joc->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayConstructor:
+			{
+				JsonArrayConstructor *jac = (JsonArrayConstructor *) node;
+
+				if (walker(jac->output, context))
+					return true;
+				if (walker(jac->exprs, context))
+					return true;
+			}
+			break;
+		case T_JsonAggConstructor:
+			{
+				JsonAggConstructor *ctor = (JsonAggConstructor *) node;
+
+				if (walker(ctor->output, context))
+					return true;
+				if (walker(ctor->agg_order, context))
+					return true;
+				if (walker(ctor->agg_filter, context))
+					return true;
+				if (walker(ctor->over, context))
+					return true;
+			}
+			break;
+		case T_JsonObjectAgg:
+			{
+				JsonObjectAgg *joa = (JsonObjectAgg *) node;
+
+				if (walker(joa->constructor, context))
+					return true;
+				if (walker(joa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayAgg:
+			{
+				JsonArrayAgg *jaa = (JsonArrayAgg *) node;
+
+				if (walker(jaa->constructor, context))
+					return true;
+				if (walker(jaa->arg, context))
+					return true;
+			}
+			break;
+		case T_JsonArrayQueryConstructor:
+			{
+				JsonArrayQueryConstructor *jaqc = (JsonArrayQueryConstructor *) node;
+
+				if (walker(jaqc->output, context))
+					return true;
+				if (walker(jaqc->query, context))
+					return true;
+			}
+			break;
+		case T_JsonIsPredicate:
+			return walker(((JsonIsPredicate *) node)->expr, context);
+		case T_JsonArgument:
+			return walker(((JsonArgument *) node)->val, context);
+		case T_JsonCommon:
+			{
+				JsonCommon *jc = (JsonCommon *) node;
+
+				if (walker(jc->expr, context))
+					return true;
+				if (walker(jc->pathspec, context))
+					return true;
+				if (walker(jc->passing, context))
+					return true;
+			}
+			break;
+		case T_JsonBehavior:
+			{
+				JsonBehavior *jb = (JsonBehavior *) node;
+
+				if (jb->btype == JSON_BEHAVIOR_DEFAULT &&
+					walker(jb->default_expr, context))
+					return true;
+			}
+			break;
+		case T_JsonFuncExpr:
+			{
+				JsonFuncExpr *jfe = (JsonFuncExpr *) node;
+
+				if (walker(jfe->common, context))
+					return true;
+				if (jfe->output && walker(jfe->output, context))
+					return true;
+				if (walker(jfe->on_empty, context))
+					return true;
+				if (walker(jfe->on_error, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 6bdad462c7..23750d97ab 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1751,6 +1751,120 @@ _outOnConflictExpr(StringInfo str, const OnConflictExpr *node)
 	WRITE_NODE_FIELD(exclRelTlist);
 }
 
+static void
+_outJsonFormat(StringInfo str, const JsonFormat *node)
+{
+	WRITE_NODE_TYPE("JSONFORMAT");
+
+	WRITE_ENUM_FIELD(format_type, JsonFormatType);
+	WRITE_ENUM_FIELD(encoding, JsonEncoding);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonReturning(StringInfo str, const JsonReturning *node)
+{
+	WRITE_NODE_TYPE("JSONRETURNING");
+
+	WRITE_NODE_FIELD(format);
+	WRITE_OID_FIELD(typid);
+	WRITE_INT_FIELD(typmod);
+}
+
+static void
+_outJsonValueExpr(StringInfo str, const JsonValueExpr *node)
+{
+	WRITE_NODE_TYPE("JSONVALUEEXPR");
+
+	WRITE_NODE_FIELD(raw_expr);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(format);
+}
+
+static void
+_outJsonConstructorExpr(StringInfo str, const JsonConstructorExpr *node)
+{
+	WRITE_NODE_TYPE("JSONCTOREXPR");
+
+	WRITE_NODE_FIELD(args);
+	WRITE_NODE_FIELD(func);
+	WRITE_NODE_FIELD(coercion);
+	WRITE_INT_FIELD(type);
+	WRITE_NODE_FIELD(returning);
+	WRITE_BOOL_FIELD(unique);
+	WRITE_BOOL_FIELD(absent_on_null);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonIsPredicate(StringInfo str, const JsonIsPredicate *node)
+{
+	WRITE_NODE_TYPE("JSONISPREDICATE");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_ENUM_FIELD(value_type, JsonValueType);
+	WRITE_BOOL_FIELD(unique_keys);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonBehavior(StringInfo str, const JsonBehavior *node)
+{
+	WRITE_NODE_TYPE("JSONBEHAVIOR");
+
+	WRITE_ENUM_FIELD(btype, JsonBehaviorType);
+	WRITE_NODE_FIELD(default_expr);
+}
+
+static void
+_outJsonExpr(StringInfo str, const JsonExpr *node)
+{
+	WRITE_NODE_TYPE("JSONEXPR");
+
+	WRITE_ENUM_FIELD(op, JsonExprOp);
+	WRITE_NODE_FIELD(formatted_expr);
+	WRITE_NODE_FIELD(result_coercion);
+	WRITE_NODE_FIELD(format);
+	WRITE_NODE_FIELD(path_spec);
+	WRITE_NODE_FIELD(passing_values);
+	WRITE_NODE_FIELD(passing_names);
+	WRITE_NODE_FIELD(returning);
+	WRITE_NODE_FIELD(on_error);
+	WRITE_NODE_FIELD(on_empty);
+	WRITE_NODE_FIELD(coercions);
+	WRITE_ENUM_FIELD(wrapper, JsonWrapper);
+	WRITE_BOOL_FIELD(omit_quotes);
+	WRITE_LOCATION_FIELD(location);
+}
+
+static void
+_outJsonCoercion(StringInfo str, const JsonCoercion *node)
+{
+	WRITE_NODE_TYPE("JSONCOERCION");
+
+	WRITE_NODE_FIELD(expr);
+	WRITE_BOOL_FIELD(via_populate);
+	WRITE_BOOL_FIELD(via_io);
+	WRITE_OID_FIELD(collation);
+}
+
+static void
+_outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
+{
+	WRITE_NODE_TYPE("JSONITEMCOERCIONS");
+
+	WRITE_NODE_FIELD(null);
+	WRITE_NODE_FIELD(string);
+	WRITE_NODE_FIELD(numeric);
+	WRITE_NODE_FIELD(boolean);
+	WRITE_NODE_FIELD(date);
+	WRITE_NODE_FIELD(time);
+	WRITE_NODE_FIELD(timetz);
+	WRITE_NODE_FIELD(timestamp);
+	WRITE_NODE_FIELD(timestamptz);
+	WRITE_NODE_FIELD(composite);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4537,6 +4651,33 @@ outNode(StringInfo str, const void *obj)
 			case T_PartitionRangeDatum:
 				_outPartitionRangeDatum(str, obj);
 				break;
+			case T_JsonFormat:
+				_outJsonFormat(str, obj);
+				break;
+			case T_JsonReturning:
+				_outJsonReturning(str, obj);
+				break;
+			case T_JsonValueExpr:
+				_outJsonValueExpr(str, obj);
+				break;
+			case T_JsonConstructorExpr:
+				_outJsonConstructorExpr(str, obj);
+				break;
+			case T_JsonIsPredicate:
+				_outJsonIsPredicate(str, obj);
+				break;
+			case T_JsonBehavior:
+				_outJsonBehavior(str, obj);
+				break;
+			case T_JsonExpr:
+				_outJsonExpr(str, obj);
+				break;
+			case T_JsonCoercion:
+				_outJsonCoercion(str, obj);
+				break;
+			case T_JsonItemCoercions:
+				_outJsonItemCoercions(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3f68f7c18d..c15e81a362 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1389,6 +1389,165 @@ _readOnConflictExpr(void)
 	READ_DONE();
 }
 
+/*
+ * _readJsonFormat
+ */
+static JsonFormat *
+_readJsonFormat(void)
+{
+	READ_LOCALS(JsonFormat);
+
+	READ_ENUM_FIELD(format_type, JsonFormatType);
+	READ_ENUM_FIELD(encoding, JsonEncoding);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonReturning
+ */
+static JsonReturning *
+_readJsonReturning(void)
+{
+	READ_LOCALS(JsonReturning);
+
+	READ_NODE_FIELD(format);
+	READ_OID_FIELD(typid);
+	READ_INT_FIELD(typmod);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonValueExpr
+ */
+static JsonValueExpr *
+_readJsonValueExpr(void)
+{
+	READ_LOCALS(JsonValueExpr);
+
+	READ_NODE_FIELD(raw_expr);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(format);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonConstructorExpr
+ */
+static JsonConstructorExpr *
+_readJsonConstructorExpr(void)
+{
+	READ_LOCALS(JsonConstructorExpr);
+
+	READ_NODE_FIELD(args);
+	READ_NODE_FIELD(func);
+	READ_NODE_FIELD(coercion);
+	READ_INT_FIELD(type);
+	READ_NODE_FIELD(returning);
+	READ_BOOL_FIELD(unique);
+	READ_BOOL_FIELD(absent_on_null);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonBehavior
+ */
+static JsonBehavior *
+_readJsonBehavior(void)
+{
+	READ_LOCALS(JsonBehavior);
+
+	READ_ENUM_FIELD(btype, JsonBehaviorType);
+	READ_NODE_FIELD(default_expr);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonExpr
+ */
+static JsonExpr *
+_readJsonExpr(void)
+{
+	READ_LOCALS(JsonExpr);
+
+	READ_ENUM_FIELD(op, JsonExprOp);
+	READ_NODE_FIELD(formatted_expr);
+	READ_NODE_FIELD(result_coercion);
+	READ_NODE_FIELD(format);
+	READ_NODE_FIELD(path_spec);
+	READ_NODE_FIELD(passing_values);
+	READ_NODE_FIELD(passing_names);
+	READ_NODE_FIELD(returning);
+	READ_NODE_FIELD(on_error);
+	READ_NODE_FIELD(on_empty);
+	READ_NODE_FIELD(coercions);
+	READ_ENUM_FIELD(wrapper, JsonWrapper);
+	READ_BOOL_FIELD(omit_quotes);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonCoercion
+ */
+static JsonCoercion *
+_readJsonCoercion(void)
+{
+	READ_LOCALS(JsonCoercion);
+
+	READ_NODE_FIELD(expr);
+	READ_BOOL_FIELD(via_populate);
+	READ_BOOL_FIELD(via_io);
+	READ_OID_FIELD(collation);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonItemCoercions
+ */
+static JsonItemCoercions *
+_readJsonItemCoercions(void)
+{
+	READ_LOCALS(JsonItemCoercions);
+
+	READ_NODE_FIELD(null);
+	READ_NODE_FIELD(string);
+	READ_NODE_FIELD(numeric);
+	READ_NODE_FIELD(boolean);
+	READ_NODE_FIELD(date);
+	READ_NODE_FIELD(time);
+	READ_NODE_FIELD(timetz);
+	READ_NODE_FIELD(timestamp);
+	READ_NODE_FIELD(timestamptz);
+	READ_NODE_FIELD(composite);
+
+	READ_DONE();
+}
+
+/*
+ * _readJsonIsPredicate
+ */
+static JsonIsPredicate *
+_readJsonIsPredicate()
+{
+	READ_LOCALS(JsonIsPredicate);
+
+	READ_NODE_FIELD(expr);
+	READ_ENUM_FIELD(value_type, JsonValueType);
+	READ_BOOL_FIELD(unique_keys);
+	READ_LOCATION_FIELD(location);
+
+	READ_DONE();
+}
+
 /*
  *	Stuff from pathnodes.h.
  *
@@ -2974,6 +3133,24 @@ parseNodeString(void)
 		return_value = _readPartitionBoundSpec();
 	else if (MATCH("PARTITIONRANGEDATUM", 19))
 		return_value = _readPartitionRangeDatum();
+	else if (MATCH("JSONFORMAT", 10))
+		return_value = _readJsonFormat();
+	else if (MATCH("JSONRETURNING", 13))
+		return_value = _readJsonReturning();
+	else if (MATCH("JSONVALUEEXPR", 13))
+		return_value = _readJsonValueExpr();
+	else if (MATCH("JSONCTOREXPR", 12))
+		return_value = _readJsonConstructorExpr();
+	else if (MATCH("JSONISPREDICATE", 15))
+		return_value = _readJsonIsPredicate();
+	else if (MATCH("JSONBEHAVIOR", 12))
+		return_value = _readJsonBehavior();
+	else if (MATCH("JSONEXPR", 8))
+		return_value = _readJsonExpr();
+	else if (MATCH("JSONCOERCION", 12))
+		return_value = _readJsonCoercion();
+	else if (MATCH("JSONITEMCOERCIONS", 17))
+		return_value = _readJsonItemCoercions();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 1b07ea392d..679d8ed597 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -4547,7 +4547,8 @@ cost_qual_eval_walker(Node *node, cost_qual_eval_context *context)
 			 IsA(node, SQLValueFunction) ||
 			 IsA(node, XmlExpr) ||
 			 IsA(node, CoerceToDomain) ||
-			 IsA(node, NextValueExpr))
+			 IsA(node, NextValueExpr) ||
+			 IsA(node, JsonExpr))
 	{
 		/* Treat all these as having cost 1 */
 		context->total.per_tuple += cpu_operator_cost;
diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c
index 413dcac036..e381ae512a 100644
--- a/src/backend/optimizer/util/clauses.c
+++ b/src/backend/optimizer/util/clauses.c
@@ -28,6 +28,7 @@
 #include "catalog/pg_type.h"
 #include "executor/executor.h"
 #include "executor/functions.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "nodes/makefuncs.h"
@@ -50,6 +51,9 @@
 #include "utils/builtins.h"
 #include "utils/datum.h"
 #include "utils/fmgroids.h"
+#include "utils/json.h"
+#include "utils/jsonb.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/syscache.h"
@@ -382,6 +386,45 @@ contain_mutable_functions_walker(Node *node, void *context)
 								context))
 		return true;
 
+	if (IsA(node, JsonConstructorExpr))
+	{
+		const JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+		ListCell   *lc;
+		bool		is_jsonb =
+			ctor->returning->format->format_type == JS_FORMAT_JSONB;
+
+		/* Check argument_type => json[b] conversions */
+		foreach(lc, ctor->args)
+		{
+			Oid			typid = exprType(lfirst(lc));
+
+			if (is_jsonb ?
+				!to_jsonb_is_immutable(typid) :
+				!to_json_is_immutable(typid))
+				return true;
+		}
+
+		/* Check all subnodes */
+	}
+
+	if (IsA(node, JsonExpr))
+	{
+		JsonExpr   *jexpr = castNode(JsonExpr, node);
+		Const	   *cnst;
+
+		if (!IsA(jexpr->path_spec, Const))
+			return true;
+
+		cnst = castNode(Const, jexpr->path_spec);
+
+		Assert(cnst->consttype == JSONPATHOID);
+		if (cnst->constisnull)
+			return false;
+
+		return jspIsMutable(DatumGetJsonPathP(cnst->constvalue),
+							jexpr->passing_names, jexpr->passing_values);
+	}
+
 	if (IsA(node, SQLValueFunction))
 	{
 		/* all variants of SQLValueFunction are stable */
@@ -853,6 +896,18 @@ max_parallel_hazard_walker(Node *node, max_parallel_hazard_context *context)
 								 context, 0);
 	}
 
+	/* JsonExpr is parallel-unsafe if subtransactions can be used. */
+	else if (IsA(node, JsonExpr))
+	{
+		JsonExpr  *jsexpr = (JsonExpr *) node;
+
+		if (ExecEvalJsonNeedsSubTransaction(jsexpr, NULL))
+		{
+			context->max_hazard = PROPARALLEL_UNSAFE;
+			return true;
+		}
+	}
+
 	/* Recurse to check arguments */
 	return expression_tree_walker(node,
 								  max_parallel_hazard_walker,
@@ -3512,6 +3567,29 @@ eval_const_expressions_mutator(Node *node,
 					return ece_evaluate_expr((Node *) newcre);
 				return (Node *) newcre;
 			}
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+				Node	   *raw = eval_const_expressions_mutator((Node *) jve->raw_expr,
+																 context);
+
+				if (raw && IsA(raw, Const))
+				{
+					Node	   *formatted;
+					Node	   *save_case_val = context->case_val;
+
+					context->case_val = raw;
+
+					formatted = eval_const_expressions_mutator((Node *) jve->formatted_expr,
+																context);
+
+					context->case_val = save_case_val;
+
+					if (formatted && IsA(formatted, Const))
+						return formatted;
+				}
+				break;
+			}
 		default:
 			break;
 	}
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index f8301541c9..ae7b3f6bb8 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -280,6 +280,13 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	struct GroupClause  *groupclause;
 	struct KeyActions	*keyactions;
 	struct KeyAction	*keyaction;
+	JsonBehavior		*jsbehavior;
+	struct
+	{
+		JsonBehavior		*on_empty;
+		JsonBehavior		*on_error;
+	} 					on_behavior;
+	JsonQuotes			js_quotes;
 }
 
 %type <node>	stmt toplevel_stmt schema_stmt routine_body_stmt
@@ -555,7 +562,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	copy_options
 
 %type <typnam>	Typename SimpleTypename ConstTypename
-				GenericType Numeric opt_float
+				GenericType Numeric opt_float JsonType
 				Character ConstCharacter
 				CharacterWithLength CharacterWithoutLength
 				ConstDatetime ConstInterval
@@ -636,6 +643,73 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <defelt>		hash_partbound_elem
 
 
+%type <node>		json_format_clause_opt
+					json_representation
+					json_value_expr
+					json_func_expr
+					json_value_func_expr
+					json_query_expr
+					json_exists_predicate
+					json_parse_expr
+					json_scalar_expr
+					json_serialize_expr
+					json_api_common_syntax
+					json_context_item
+					json_argument
+					json_output_clause_opt
+					json_returning_clause_opt
+					json_value_constructor
+					json_object_constructor
+					json_object_constructor_args
+					json_object_constructor_args_opt
+					json_object_args
+					json_object_func_args
+					json_array_constructor
+					json_name_and_value
+					json_aggregate_func
+					json_object_aggregate_constructor
+					json_array_aggregate_constructor
+					json_path_specification
+
+%type <list>		json_name_and_value_list
+					json_value_expr_list
+					json_array_aggregate_order_by_clause_opt
+					json_arguments
+					json_passing_clause_opt
+
+%type <str>			json_table_path_name
+					json_as_path_name_clause_opt
+
+%type <ival>		json_encoding
+					json_encoding_clause_opt
+					json_wrapper_clause_opt
+					json_wrapper_behavior
+					json_conditional_or_unconditional_opt
+					json_predicate_type_constraint_opt
+
+%type <jsbehavior>	json_behavior_error
+					json_behavior_null
+					json_behavior_true
+					json_behavior_false
+					json_behavior_unknown
+					json_behavior_empty_array
+					json_behavior_empty_object
+					json_behavior_default
+					json_value_behavior
+					json_query_behavior
+					json_exists_error_behavior
+					json_exists_error_clause_opt
+
+%type <on_behavior> json_value_on_behavior_clause_opt
+					json_query_on_behavior_clause_opt
+
+%type <js_quotes>	json_quotes_behavior
+					json_quotes_clause_opt
+
+%type <boolean>		json_key_uniqueness_constraint_opt
+					json_object_constructor_null_clause_opt
+					json_array_constructor_null_clause_opt
+
 /*
  * Non-keyword token types.  These are hard-wired into the "flex" lexer.
  * They must be listed first so that their numeric codes do not depend on
@@ -661,7 +735,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 
 /* ordinary key words in alphabetical order */
-%token <keyword> ABORT_P ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
+%token <keyword> ABORT_P ABSENT ABSOLUTE_P ACCESS ACTION ADD_P ADMIN AFTER
 	AGGREGATE ALL ALSO ALTER ALWAYS ANALYSE ANALYZE AND ANY ARRAY AS ASC
 	ASENSITIVE ASSERTION ASSIGNMENT ASYMMETRIC ATOMIC AT ATTACH ATTRIBUTE AUTHORIZATION
 
@@ -671,7 +745,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
 	CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
 	CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
-	COMMITTED COMPRESSION CONCURRENTLY CONFIGURATION CONFLICT
+	COMMITTED COMPRESSION CONCURRENTLY CONDITIONAL CONFIGURATION CONFLICT
 	CONNECTION CONSTRAINT CONSTRAINTS CONTENT_P CONTINUE_P CONVERSION_P COPY
 	COST CREATE CROSS CSV CUBE CURRENT_P
 	CURRENT_CATALOG CURRENT_DATE CURRENT_ROLE CURRENT_SCHEMA
@@ -682,12 +756,12 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
 	DOUBLE_P DROP
 
-	EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
-	EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
+	EACH ELSE EMPTY_P ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ERROR_P ESCAPE
+	EVENT EXCEPT EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
 	EXTENSION EXTERNAL EXTRACT
 
 	FALSE_P FAMILY FETCH FILTER FINALIZE FIRST_P FLOAT_P FOLLOWING FOR
-	FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
+	FORCE FOREIGN FORMAT FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
 
 	GENERATED GLOBAL GRANT GRANTED GREATEST GROUP_P GROUPING GROUPS
 
@@ -698,9 +772,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
-	JOIN
+	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
 
-	KEY
+	KEY KEYS KEEP
 
 	LABEL LANGUAGE LARGE_P LAST_P LATERAL_P
 	LEADING LEAKPROOF LEAST LEFT LEVEL LIKE LIMIT LISTEN LOAD LOCAL
@@ -713,7 +788,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
-	OBJECT_P OF OFF OFFSET OIDS OLD ON ONLY OPERATOR OPTION OPTIONS OR
+	OBJECT_P OF OFF OFFSET OIDS OLD OMIT ON ONLY OPERATOR OPTION OPTIONS OR
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
@@ -721,17 +796,17 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
-	QUOTE
+	QUOTE QUOTES
 
 	RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
 	REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
 	RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
 	ROUTINE ROUTINES ROW ROWS RULE
 
-	SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
-	SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
-	SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
-	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRIP_P
+	SAVEPOINT SCALAR SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT
+	SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF
+	SHARE SHOW SIMILAR SIMPLE SKIP SMALLINT SNAPSHOT SOME SQL_P STABLE STANDALONE_P
+	START STATEMENT STATISTICS STDIN STDOUT STORAGE STORED STRICT_P STRING STRIP_P
 	SUBSCRIPTION SUBSTRING SUPPORT SYMMETRIC SYSID SYSTEM_P
 
 	TABLE TABLES TABLESAMPLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN
@@ -739,7 +814,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	TREAT TRIGGER TRIM TRUE_P
 	TRUNCATE TRUSTED TYPE_P TYPES_P
 
-	UESCAPE UNBOUNDED UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
+	UESCAPE UNBOUNDED UNCONDITIONAL UNCOMMITTED UNENCRYPTED UNION UNIQUE UNKNOWN
 	UNLISTEN UNLOGGED UNTIL UPDATE USER USING
 
 	VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
@@ -764,7 +839,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * as NOT, at least with respect to their left-hand subexpression.
  * NULLS_LA and WITH_LA are needed to make the grammar LALR(1).
  */
-%token		NOT_LA NULLS_LA WITH_LA
+%token		NOT_LA NULLS_LA WITH_LA WITH_LA_UNIQUE WITHOUT_LA
 
 /*
  * The grammar likewise thinks these tokens are keywords, but they are never
@@ -782,6 +857,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 /* Precedence: lowest to highest */
 %nonassoc	SET				/* see relation_expr_opt_alias */
+%right		FORMAT
 %left		UNION EXCEPT
 %left		INTERSECT
 %left		OR
@@ -817,11 +893,15 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  * Using the same precedence as IDENT seems right for the reasons given above.
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
+%nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
 %left		'*' '/' '%'
 %left		'^'
+%left		KEYS						/* UNIQUE [ KEYS ] */
+%left		OBJECT_P SCALAR VALUE_P		/* JSON [ OBJECT | SCALAR | VALUE ] */
 /* Unary Operators */
 %left		AT				/* sets precedence for AT TIME ZONE */
 %left		COLLATE
@@ -839,6 +919,9 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	empty_json_unique
+%left		WITHOUT WITH_LA_UNIQUE
+
 %%
 
 /*
@@ -13087,6 +13170,7 @@ SimpleTypename:
 					$$->typmods = list_make2(makeIntConst(INTERVAL_FULL_RANGE, -1),
 											 makeIntConst($3, @3));
 				}
+			| JsonType								{ $$ = $1; }
 		;
 
 /* We have a separate ConstTypename to allow defaulting fixed-length
@@ -13105,6 +13189,7 @@ ConstTypename:
 			| ConstBit								{ $$ = $1; }
 			| ConstCharacter						{ $$ = $1; }
 			| ConstDatetime							{ $$ = $1; }
+			| JsonType								{ $$ = $1; }
 		;
 
 /*
@@ -13398,7 +13483,7 @@ ConstInterval:
 
 opt_timezone:
 			WITH_LA TIME ZONE						{ $$ = true; }
-			| WITHOUT TIME ZONE						{ $$ = false; }
+			| WITHOUT_LA TIME ZONE					{ $$ = false; }
 			| /*EMPTY*/								{ $$ = false; }
 		;
 
@@ -13473,6 +13558,13 @@ interval_second:
 				}
 		;
 
+JsonType:
+			JSON
+				{
+					$$ = SystemTypeName("json");
+					$$->location = @1;
+				}
+		;
 
 /*****************************************************************************
  *
@@ -13929,6 +14021,46 @@ a_expr:		c_expr									{ $$ = $1; }
 														   @2),
 									 @2);
 				}
+			| a_expr
+				IS json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeJsonIsPredicate($1, format, $3, $4, @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS  json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeJsonIsPredicate($1, $3, $5, $6, @1);
+				}
+			*/
+			| a_expr
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec IS
+				{
+					JsonFormat *format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					$$ = makeNotExpr(makeJsonIsPredicate($1, format, $4, $5, @1), @1);
+				}
+			/*
+			 * Required by standard, but it would conflict with expressions
+			 * like: 'str' || format(...)
+			| a_expr
+				FORMAT json_representation
+				IS NOT
+					json_predicate_type_constraint_opt
+					json_key_uniqueness_constraint_opt		%prec FORMAT
+				{
+					$3.location = @2;
+					$$ = makeNotExpr(makeJsonIsPredicate($1, $3, $6, $7, @1), @1);
+				}
+			*/
 			| DEFAULT
 				{
 					/*
@@ -14011,6 +14143,25 @@ b_expr:		c_expr
 				}
 		;
 
+json_predicate_type_constraint_opt:
+			JSON									{ $$ = JS_TYPE_ANY; }
+			| JSON VALUE_P							{ $$ = JS_TYPE_ANY; }
+			| JSON ARRAY							{ $$ = JS_TYPE_ARRAY; }
+			| JSON OBJECT_P							{ $$ = JS_TYPE_OBJECT; }
+			| JSON SCALAR							{ $$ = JS_TYPE_SCALAR; }
+		;
+
+json_key_uniqueness_constraint_opt:
+			WITH_LA_UNIQUE unique_keys				{ $$ = true; }
+			| WITHOUT unique_keys					{ $$ = false; }
+			| /* EMPTY */ %prec empty_json_unique	{ $$ = false; }
+		;
+
+unique_keys:
+			UNIQUE
+			| UNIQUE KEYS
+		;
+
 /*
  * Productions that can be used in both a_expr and b_expr.
  *
@@ -14263,6 +14414,15 @@ func_expr: func_application within_group_clause filter_clause over_clause
 					n->over = $4;
 					$$ = (Node *) n;
 				}
+			| json_aggregate_func filter_clause over_clause
+				{
+					JsonAggConstructor *n = IsA($1, JsonObjectAgg) ?
+						((JsonObjectAgg *) $1)->constructor :
+						((JsonArrayAgg *) $1)->constructor;
+					n->agg_filter = $2;
+					n->over = $3;
+					$$ = (Node *) $1;
+				}
 			| func_expr_common_subexpr
 				{ $$ = $1; }
 		;
@@ -14276,6 +14436,7 @@ func_expr: func_application within_group_clause filter_clause over_clause
 func_expr_windowless:
 			func_application						{ $$ = $1; }
 			| func_expr_common_subexpr				{ $$ = $1; }
+			| json_aggregate_func					{ $$ = $1; }
 		;
 
 /*
@@ -14563,6 +14724,8 @@ func_expr_common_subexpr:
 					n->location = @1;
 					$$ = (Node *)n;
 				}
+			| json_func_expr
+				{ $$ = $1; }
 		;
 
 /*
@@ -15261,6 +15424,530 @@ opt_asymmetric: ASYMMETRIC
 			| /*EMPTY*/
 		;
 
+/* SQL/JSON support */
+json_func_expr:
+			json_value_constructor
+			| json_value_func_expr
+			| json_query_expr
+			| json_exists_predicate
+			| json_parse_expr
+			| json_scalar_expr
+			| json_serialize_expr
+		;
+
+json_parse_expr:
+			JSON '(' json_value_expr json_key_uniqueness_constraint_opt
+					 json_returning_clause_opt ')'
+				{
+					JsonParseExpr *n = makeNode(JsonParseExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->unique_keys = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_scalar_expr:
+			JSON_SCALAR '(' a_expr json_returning_clause_opt ')'
+				{
+					JsonScalarExpr *n = makeNode(JsonScalarExpr);
+					n->expr = (Expr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_serialize_expr:
+			JSON_SERIALIZE '(' json_value_expr json_output_clause_opt ')'
+				{
+					JsonSerializeExpr *n = makeNode(JsonSerializeExpr);
+					n->expr = (JsonValueExpr *) $3;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_func_expr:
+			JSON_VALUE '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_value_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_VALUE;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->on_empty = $5.on_empty;
+					n->on_error = $5.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_api_common_syntax:
+			json_context_item ',' json_path_specification
+			json_as_path_name_clause_opt
+			json_passing_clause_opt
+				{
+					JsonCommon *n = makeNode(JsonCommon);
+					n->expr = (JsonValueExpr *) $1;
+					n->pathspec = $3;
+					n->pathname = $4;
+					n->passing = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_context_item:
+			json_value_expr							{ $$ = $1; }
+		;
+
+json_path_specification:
+			a_expr									{ $$ = $1; }
+		;
+
+json_as_path_name_clause_opt:
+			 AS json_table_path_name				{ $$ = $2; }
+			 | /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_path_name:
+			name									{ $$ = $1; }
+		;
+
+json_passing_clause_opt:
+			PASSING json_arguments					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
+
+json_arguments:
+			json_argument							{ $$ = list_make1($1); }
+			| json_arguments ',' json_argument		{ $$ = lappend($1, $3); }
+		;
+
+json_argument:
+			json_value_expr AS ColLabel
+			{
+				JsonArgument *n = makeNode(JsonArgument);
+				n->val = (JsonValueExpr *) $1;
+				n->name = $3;
+				$$ = (Node *) n;
+			}
+		;
+
+json_value_expr:
+			a_expr json_format_clause_opt
+			{
+				$$ = (Node *) makeJsonValueExpr((Expr *) $1, castNode(JsonFormat, $2));
+			}
+		;
+
+json_format_clause_opt:
+			FORMAT json_representation
+				{
+					$$ = $2;
+					castNode(JsonFormat, $$)->location = @1;
+				}
+			| /* EMPTY */
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+				}
+		;
+
+json_representation:
+			JSON json_encoding_clause_opt
+				{
+					$$ = (Node *) makeJsonFormat(JS_FORMAT_JSON, $2, @1);
+				}
+		/*	| other implementation defined JSON representation options (BSON, AVRO etc) */
+		;
+
+json_encoding_clause_opt:
+			ENCODING json_encoding					{ $$ = $2; }
+			| /* EMPTY */							{ $$ = JS_ENC_DEFAULT; }
+		;
+
+json_encoding:
+			name									{ $$ = makeJsonEncoding($1); }
+		;
+
+json_behavior_error:
+			ERROR_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL); }
+		;
+
+json_behavior_null:
+			NULL_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_NULL, NULL); }
+		;
+
+json_behavior_true:
+			TRUE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_TRUE, NULL); }
+		;
+
+json_behavior_false:
+			FALSE_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_FALSE, NULL); }
+		;
+
+json_behavior_unknown:
+			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
+		;
+
+json_behavior_empty_array:
+			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+			/* non-standard, for Oracle compatibility only */
+			| EMPTY_P 		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
+		;
+
+json_behavior_empty_object:
+			EMPTY_P OBJECT_P	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
+json_behavior_default:
+			DEFAULT a_expr	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_DEFAULT, $2); }
+		;
+
+
+json_value_behavior:
+			json_behavior_null
+			| json_behavior_error
+			| json_behavior_default
+		;
+
+json_value_on_behavior_clause_opt:
+			json_value_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_value_behavior ON EMPTY_P json_value_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_value_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_query_expr:
+			JSON_QUERY '('
+				json_api_common_syntax
+				json_output_clause_opt
+				json_wrapper_clause_opt
+				json_quotes_clause_opt
+				json_query_on_behavior_clause_opt
+			')'
+				{
+					JsonFuncExpr *n = makeNode(JsonFuncExpr);
+					n->op = IS_JSON_QUERY;
+					n->common = (JsonCommon *) $3;
+					n->output = (JsonOutput *) $4;
+					n->wrapper = $5;
+					if (n->wrapper != JSW_NONE && $6 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@6)));
+					n->omit_quotes = $6 == JS_QUOTES_OMIT;
+					n->on_empty = $7.on_empty;
+					n->on_error = $7.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_wrapper_clause_opt:
+			json_wrapper_behavior WRAPPER			{ $$ = $1; }
+			| /* EMPTY */							{ $$ = 0; }
+		;
+
+json_wrapper_behavior:
+			WITHOUT array_opt						{ $$ = JSW_NONE; }
+			| WITH json_conditional_or_unconditional_opt array_opt { $$ = $2; }
+		;
+
+array_opt:
+			ARRAY									{ }
+			| /* EMPTY */							{ }
+		;
+
+json_conditional_or_unconditional_opt:
+			CONDITIONAL								{ $$ = JSW_CONDITIONAL; }
+			| UNCONDITIONAL							{ $$ = JSW_UNCONDITIONAL; }
+			| /* EMPTY */							{ $$ = JSW_UNCONDITIONAL; }
+		;
+
+json_quotes_clause_opt:
+			json_quotes_behavior QUOTES json_on_scalar_string_opt { $$ = $1; }
+			| /* EMPTY */							{ $$ = JS_QUOTES_UNSPEC; }
+		;
+
+json_quotes_behavior:
+			KEEP									{ $$ = JS_QUOTES_KEEP; }
+			| OMIT									{ $$ = JS_QUOTES_OMIT; }
+		;
+
+json_on_scalar_string_opt:
+			ON SCALAR STRING						{ }
+			| /* EMPTY */							{ }
+		;
+
+json_query_behavior:
+			json_behavior_error
+			| json_behavior_null
+			| json_behavior_empty_array
+			| json_behavior_empty_object
+			| json_behavior_default
+		;
+
+json_query_on_behavior_clause_opt:
+			json_query_behavior ON EMPTY_P
+									{ $$.on_empty = $1; $$.on_error = NULL; }
+			| json_query_behavior ON EMPTY_P json_query_behavior ON ERROR_P
+									{ $$.on_empty = $1; $$.on_error = $4; }
+			| json_query_behavior ON ERROR_P
+									{ $$.on_empty = NULL; $$.on_error = $1; }
+			|  /* EMPTY */
+									{ $$.on_empty = NULL; $$.on_error = NULL; }
+		;
+
+json_returning_clause_opt:
+			RETURNING Typename
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format =
+						makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, @2);
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_output_clause_opt:
+			RETURNING Typename json_format_clause_opt
+				{
+					JsonOutput *n = makeNode(JsonOutput);
+					n->typeName = $2;
+					n->returning = makeNode(JsonReturning);
+					n->returning->format = (JsonFormat *) $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */							{ $$ = NULL; }
+			;
+
+json_exists_predicate:
+			JSON_EXISTS '('
+				json_api_common_syntax
+				json_returning_clause_opt
+				json_exists_error_clause_opt
+			')'
+				{
+					JsonFuncExpr *p = makeNode(JsonFuncExpr);
+					p->op = IS_JSON_EXISTS;
+					p->common = (JsonCommon *) $3;
+					p->output = (JsonOutput *) $4;
+					p->on_error = $5;
+					p->location = @1;
+					$$ = (Node *) p;
+				}
+		;
+
+json_exists_error_clause_opt:
+			json_exists_error_behavior ON ERROR_P		{ $$ = $1; }
+			| /* EMPTY */								{ $$ = NULL; }
+		;
+
+json_exists_error_behavior:
+			json_behavior_error
+			| json_behavior_true
+			| json_behavior_false
+			| json_behavior_unknown
+		;
+
+json_value_constructor:
+			json_object_constructor
+			| json_array_constructor
+		;
+
+json_object_constructor:
+			JSON_OBJECT '(' json_object_args ')'
+				{
+					$$ = $3;
+				}
+		;
+
+json_object_args:
+			json_object_constructor_args
+			| json_object_func_args
+		;
+
+json_object_func_args:
+			func_arg_list
+				{
+					List *func = list_make1(makeString("json_object"));
+					$$ = (Node *) makeFuncCall(func, $1, COERCE_EXPLICIT_CALL, @1);
+				}
+		;
+
+json_object_constructor_args:
+			json_object_constructor_args_opt json_output_clause_opt
+				{
+					JsonObjectConstructor *n = (JsonObjectConstructor *) $1;
+					n->output = (JsonOutput *) $2;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_object_constructor_args_opt:
+			json_name_and_value_list
+			json_object_constructor_null_clause_opt
+			json_key_uniqueness_constraint_opt
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = $1;
+					n->absent_on_null = $2;
+					n->unique = $3;
+					$$ = (Node *) n;
+				}
+			| /* EMPTY */
+				{
+					JsonObjectConstructor *n = makeNode(JsonObjectConstructor);
+					n->exprs = NULL;
+					n->absent_on_null = false;
+					n->unique = false;
+					$$ = (Node *) n;
+				}
+		;
+
+json_name_and_value_list:
+			json_name_and_value
+				{ $$ = list_make1($1); }
+			| json_name_and_value_list ',' json_name_and_value
+				{ $$ = lappend($1, $3); }
+		;
+
+json_name_and_value:
+/* TODO This is not supported due to conflicts
+			KEY c_expr VALUE_P json_value_expr %prec POSTFIXOP
+				{ $$ = makeJsonKeyValue($2, $4); }
+			|
+*/
+			c_expr VALUE_P json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+			|
+			a_expr ':' json_value_expr
+				{ $$ = makeJsonKeyValue($1, $3); }
+		;
+
+json_object_constructor_null_clause_opt:
+			NULL_P ON NULL_P					{ $$ = false; }
+			| ABSENT ON NULL_P					{ $$ = true; }
+			| /* EMPTY */						{ $$ = false; }
+		;
+
+json_array_constructor:
+			JSON_ARRAY '('
+				json_value_expr_list
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = $3;
+					n->absent_on_null = $4;
+					n->output = (JsonOutput *) $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				select_no_parens
+				/* json_format_clause_opt */
+				/* json_array_constructor_null_clause_opt */
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayQueryConstructor *n = makeNode(JsonArrayQueryConstructor);
+					n->query = $3;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					/* n->format = $4; */
+					n->absent_on_null = true /* $5 */;
+					n->output = (JsonOutput *) $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| JSON_ARRAY '('
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayConstructor *n = makeNode(JsonArrayConstructor);
+					n->exprs = NIL;
+					n->absent_on_null = true;
+					n->output = (JsonOutput *) $3;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_value_expr_list:
+			json_value_expr								{ $$ = list_make1($1); }
+			| json_value_expr_list ',' json_value_expr	{ $$ = lappend($1, $3);}
+		;
+
+json_array_constructor_null_clause_opt:
+			NULL_P ON NULL_P						{ $$ = false; }
+			| ABSENT ON NULL_P						{ $$ = true; }
+			| /* EMPTY */							{ $$ = true; }
+		;
+
+json_aggregate_func:
+			json_object_aggregate_constructor
+			| json_array_aggregate_constructor
+		;
+
+json_object_aggregate_constructor:
+			JSON_OBJECTAGG '('
+				json_name_and_value
+				json_object_constructor_null_clause_opt
+				json_key_uniqueness_constraint_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonObjectAgg *n = makeNode(JsonObjectAgg);
+					n->arg = (JsonKeyValue *) $3;
+					n->absent_on_null = $4;
+					n->unique = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->agg_order = NULL;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_constructor:
+			JSON_ARRAYAGG '('
+				json_value_expr
+				json_array_aggregate_order_by_clause_opt
+				json_array_constructor_null_clause_opt
+				json_output_clause_opt
+			')'
+				{
+					JsonArrayAgg *n = makeNode(JsonArrayAgg);
+					n->arg = (JsonValueExpr *) $3;
+					n->absent_on_null = $5;
+					n->constructor = makeNode(JsonAggConstructor);
+					n->constructor->agg_order = $4;
+					n->constructor->output = (JsonOutput *) $6;
+					n->constructor->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_array_aggregate_order_by_clause_opt:
+			ORDER BY sortby_list					{ $$ = $3; }
+			| /* EMPTY */							{ $$ = NIL; }
+		;
 
 /*****************************************************************************
  *
@@ -15706,6 +16393,7 @@ BareColLabel:	IDENT								{ $$ = $1; }
  */
 unreserved_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -15746,6 +16434,7 @@ unreserved_keyword:
 			| COMMIT
 			| COMMITTED
 			| COMPRESSION
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -15782,10 +16471,12 @@ unreserved_keyword:
 			| DOUBLE_P
 			| DROP
 			| EACH
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -15802,6 +16493,7 @@ unreserved_keyword:
 			| FIRST_P
 			| FOLLOWING
 			| FORCE
+			| FORMAT
 			| FORWARD
 			| FUNCTION
 			| FUNCTIONS
@@ -15833,7 +16525,9 @@ unreserved_keyword:
 			| INSTEAD
 			| INVOKER
 			| ISOLATION
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -15876,6 +16570,7 @@ unreserved_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| OPERATOR
 			| OPTION
 			| OPTIONS
@@ -15905,6 +16600,7 @@ unreserved_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REASSIGN
@@ -15934,6 +16630,7 @@ unreserved_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -15985,6 +16682,7 @@ unreserved_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNKNOWN
 			| UNLISTEN
@@ -16042,6 +16740,16 @@ col_name_keyword:
 			| INT_P
 			| INTEGER
 			| INTERVAL
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
 			| LEAST
 			| NATIONAL
 			| NCHAR
@@ -16109,6 +16817,7 @@ type_func_name_keyword:
 			| OVERLAPS
 			| RIGHT
 			| SIMILAR
+			| STRING
 			| TABLESAMPLE
 			| VERBOSE
 		;
@@ -16210,6 +16919,7 @@ reserved_keyword:
  */
 bare_label_keyword:
 			  ABORT_P
+			| ABSENT
 			| ABSOLUTE_P
 			| ACCESS
 			| ACTION
@@ -16272,6 +16982,7 @@ bare_label_keyword:
 			| COMMITTED
 			| COMPRESSION
 			| CONCURRENTLY
+			| CONDITIONAL
 			| CONFIGURATION
 			| CONFLICT
 			| CONNECTION
@@ -16324,11 +17035,13 @@ bare_label_keyword:
 			| DROP
 			| EACH
 			| ELSE
+			| EMPTY_P
 			| ENABLE_P
 			| ENCODING
 			| ENCRYPTED
 			| END_P
 			| ENUM_P
+			| ERROR_P
 			| ESCAPE
 			| EVENT
 			| EXCLUDE
@@ -16349,6 +17062,7 @@ bare_label_keyword:
 			| FOLLOWING
 			| FORCE
 			| FOREIGN
+			| FORMAT
 			| FORWARD
 			| FREEZE
 			| FULL
@@ -16393,7 +17107,19 @@ bare_label_keyword:
 			| IS
 			| ISOLATION
 			| JOIN
+			| JSON
+			| JSON_ARRAY
+			| JSON_ARRAYAGG
+			| JSON_EXISTS
+			| JSON_OBJECT
+			| JSON_OBJECTAGG
+			| JSON_QUERY
+			| JSON_SCALAR
+			| JSON_SERIALIZE
+			| JSON_VALUE
+			| KEEP
 			| KEY
+			| KEYS
 			| LABEL
 			| LANGUAGE
 			| LARGE_P
@@ -16450,6 +17176,7 @@ bare_label_keyword:
 			| OFF
 			| OIDS
 			| OLD
+			| OMIT
 			| ONLY
 			| OPERATOR
 			| OPTION
@@ -16486,6 +17213,7 @@ bare_label_keyword:
 			| PROGRAM
 			| PUBLICATION
 			| QUOTE
+			| QUOTES
 			| RANGE
 			| READ
 			| REAL
@@ -16519,6 +17247,7 @@ bare_label_keyword:
 			| ROWS
 			| RULE
 			| SAVEPOINT
+			| SCALAR
 			| SCHEMA
 			| SCHEMAS
 			| SCROLL
@@ -16553,6 +17282,7 @@ bare_label_keyword:
 			| STORAGE
 			| STORED
 			| STRICT_P
+			| STRING
 			| STRIP_P
 			| SUBSCRIPTION
 			| SUBSTRING
@@ -16586,6 +17316,7 @@ bare_label_keyword:
 			| UESCAPE
 			| UNBOUNDED
 			| UNCOMMITTED
+			| UNCONDITIONAL
 			| UNENCRYPTED
 			| UNIQUE
 			| UNKNOWN
diff --git a/src/backend/parser/parse_collate.c b/src/backend/parser/parse_collate.c
index 6c793b72ec..2e549e7b39 100644
--- a/src/backend/parser/parse_collate.c
+++ b/src/backend/parser/parse_collate.c
@@ -690,6 +690,10 @@ assign_collations_walker(Node *node, assign_collations_context *context)
 															&loccontext);
 						}
 						break;
+					case T_JsonExpr:
+						/* Context item and PASSING arguments are already
+						 * marked with collations in parse_expr.c. */
+						break;
 					default:
 
 						/*
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 1c09ea24cd..18622fd013 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -15,6 +15,8 @@
 
 #include "postgres.h"
 
+#include "catalog/pg_aggregate.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/dbcommands.h"
 #include "miscadmin.h"
@@ -34,6 +36,7 @@
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/fmgroids.h"
 #include "utils/lsyscache.h"
 #include "utils/timestamp.h"
 #include "utils/xml.h"
@@ -74,6 +77,21 @@ static Node *transformWholeRowRef(ParseState *pstate,
 static Node *transformIndirection(ParseState *pstate, A_Indirection *ind);
 static Node *transformTypeCast(ParseState *pstate, TypeCast *tc);
 static Node *transformCollateClause(ParseState *pstate, CollateClause *c);
+static Node *transformJsonObjectConstructor(ParseState *pstate,
+											JsonObjectConstructor *ctor);
+static Node *transformJsonArrayConstructor(ParseState *pstate,
+										   JsonArrayConstructor *ctor);
+static Node *transformJsonArrayQueryConstructor(ParseState *pstate,
+												JsonArrayQueryConstructor *ctor);
+static Node *transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg);
+static Node *transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg);
+static Node *transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *p);
+static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *p);
+static Node *transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve);
+static Node *transformJsonParseExpr(ParseState *pstate, JsonParseExpr *expr);
+static Node *transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *expr);
+static Node *transformJsonSerializeExpr(ParseState *pstate,
+										JsonSerializeExpr *expr);
 static Node *make_row_comparison_op(ParseState *pstate, List *opname,
 									List *largs, List *rargs, int location);
 static Node *make_row_distinct_op(ParseState *pstate, List *opname,
@@ -301,6 +319,50 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 				break;
 			}
 
+		case T_JsonObjectConstructor:
+			result = transformJsonObjectConstructor(pstate, (JsonObjectConstructor *) expr);
+			break;
+
+		case T_JsonArrayConstructor:
+			result = transformJsonArrayConstructor(pstate, (JsonArrayConstructor *) expr);
+			break;
+
+		case T_JsonArrayQueryConstructor:
+			result = transformJsonArrayQueryConstructor(pstate, (JsonArrayQueryConstructor *) expr);
+			break;
+
+		case T_JsonObjectAgg:
+			result = transformJsonObjectAgg(pstate, (JsonObjectAgg *) expr);
+			break;
+
+		case T_JsonArrayAgg:
+			result = transformJsonArrayAgg(pstate, (JsonArrayAgg *) expr);
+			break;
+
+		case T_JsonIsPredicate:
+			result = transformJsonIsPredicate(pstate, (JsonIsPredicate *) expr);
+			break;
+
+		case T_JsonFuncExpr:
+			result = transformJsonFuncExpr(pstate, (JsonFuncExpr *) expr);
+			break;
+
+		case T_JsonValueExpr:
+			result = transformJsonValueExpr(pstate, (JsonValueExpr *) expr);
+			break;
+
+		case T_JsonParseExpr:
+			result = transformJsonParseExpr(pstate, (JsonParseExpr *) expr);
+			break;
+
+		case T_JsonScalarExpr:
+			result = transformJsonScalarExpr(pstate, (JsonScalarExpr *) expr);
+			break;
+
+		case T_JsonSerializeExpr:
+			result = transformJsonSerializeExpr(pstate, (JsonSerializeExpr *) expr);
+			break;
+
 		default:
 			/* should not reach here */
 			elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr));
@@ -3099,3 +3161,1407 @@ ParseExprKindName(ParseExprKind exprKind)
 	}
 	return "unrecognized expression kind";
 }
+
+/*
+ * Make string Const node from JSON encoding name.
+ *
+ * UTF8 is default encoding.
+ */
+static Const *
+getJsonEncodingConst(JsonFormat *format)
+{
+	JsonEncoding encoding;
+	const char *enc;
+	Name		encname = palloc(sizeof(NameData));
+
+	if (!format ||
+		format->format_type == JS_FORMAT_DEFAULT ||
+		format->encoding == JS_ENC_DEFAULT)
+		encoding = JS_ENC_UTF8;
+	else
+		encoding = format->encoding;
+
+	switch (encoding)
+	{
+		case JS_ENC_UTF16:
+			enc = "UTF16";
+			break;
+		case JS_ENC_UTF32:
+			enc = "UTF32";
+			break;
+		case JS_ENC_UTF8:
+			enc = "UTF8";
+			break;
+		default:
+			elog(ERROR, "invalid JSON encoding: %d", encoding);
+			break;
+	}
+
+	namestrcpy(encname, enc);
+
+	return makeConst(NAMEOID, -1, InvalidOid, NAMEDATALEN,
+					 NameGetDatum(encname), false, false);
+}
+
+/*
+ * Make bytea => text conversion using specified JSON format encoding.
+ */
+static Node *
+makeJsonByteaToTextConversion(Node *expr, JsonFormat *format, int location)
+{
+	Const	   *encoding = getJsonEncodingConst(format);
+	FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_FROM, TEXTOID,
+									 list_make2(expr, encoding),
+									 InvalidOid, InvalidOid,
+									 COERCE_EXPLICIT_CALL);
+
+	fexpr->location = location;
+
+	return (Node *) fexpr;
+}
+
+/*
+ * Make CaseTestExpr node.
+ */
+static Node *
+makeCaseTestExpr(Node *expr)
+{
+	CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+	placeholder->typeId = exprType(expr);
+	placeholder->typeMod = exprTypmod(expr);
+	placeholder->collation = exprCollation(expr);
+
+	return (Node *) placeholder;
+}
+
+/*
+ * Transform JSON value expression using specified input JSON format or
+ * default format otherwise.
+ */
+static Node *
+transformJsonValueExprExt(ParseState *pstate, JsonValueExpr *ve,
+						  JsonFormatType default_format, bool isarg,
+						  Oid targettype)
+{
+	Node	   *expr = transformExprRecurse(pstate, (Node *) ve->raw_expr);
+	Node	   *rawexpr;
+	JsonFormatType format;
+	Oid			exprtype;
+	int			location;
+	char		typcategory;
+	bool		typispreferred;
+
+	if (exprType(expr) == UNKNOWNOID)
+		expr = coerce_to_specific_type(pstate, expr, TEXTOID, "JSON_VALUE_EXPR");
+
+	rawexpr = expr;
+	exprtype = exprType(expr);
+	location = exprLocation(expr);
+
+	get_type_category_preferred(exprtype, &typcategory, &typispreferred);
+
+	rawexpr = expr;
+
+	if (ve->format->format_type != JS_FORMAT_DEFAULT)
+	{
+		if (ve->format->encoding != JS_ENC_DEFAULT && exprtype != BYTEAOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("JSON ENCODING clause is only allowed for bytea input type"),
+					 parser_errposition(pstate, ve->format->location)));
+
+		if (exprtype == JSONOID || exprtype == JSONBOID)
+		{
+			format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+			ereport(WARNING,
+					(errmsg("FORMAT JSON has no effect for json and jsonb types"),
+					 parser_errposition(pstate, ve->format->location)));
+		}
+		else
+			format = ve->format->format_type;
+	}
+	else if (isarg)
+	{
+		/* Pass SQL/JSON item types directly without conversion to json[b]. */
+		switch (exprtype)
+		{
+			case TEXTOID:
+			case NUMERICOID:
+			case BOOLOID:
+			case INT2OID:
+			case INT4OID:
+			case INT8OID:
+			case FLOAT4OID:
+			case FLOAT8OID:
+			case DATEOID:
+			case TIMEOID:
+			case TIMETZOID:
+			case TIMESTAMPOID:
+			case TIMESTAMPTZOID:
+				return expr;
+
+			default:
+				if (typcategory == TYPCATEGORY_STRING)
+					return coerce_to_specific_type(pstate, expr, TEXTOID,
+												   "JSON_VALUE_EXPR");
+				/* else convert argument to json[b] type */
+				break;
+		}
+
+		format = default_format;
+	}
+	else if (exprtype == JSONOID || exprtype == JSONBOID)
+		format = JS_FORMAT_DEFAULT;	/* do not format json[b] types */
+	else
+		format = default_format;
+
+	if (format == JS_FORMAT_DEFAULT &&
+		(!OidIsValid(targettype) || exprtype == targettype))
+		expr = rawexpr;
+	else
+	{
+		Node	   *orig = makeCaseTestExpr(expr);
+		Node	   *coerced;
+		bool		cast_is_needed = OidIsValid(targettype);
+
+		if (!isarg && !cast_is_needed &&
+			exprtype != BYTEAOID && typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg(ve->format->format_type == JS_FORMAT_DEFAULT ?
+							"cannot use non-string types with implicit FORMAT JSON clause" :
+							"cannot use non-string types with explicit FORMAT JSON clause"),
+					 parser_errposition(pstate, ve->format->location >= 0 ?
+										ve->format->location : location)));
+
+		expr = orig;
+
+		/* Convert encoded JSON text from bytea. */
+		if (format == JS_FORMAT_JSON && exprtype == BYTEAOID)
+		{
+			expr = makeJsonByteaToTextConversion(expr, ve->format, location);
+			exprtype = TEXTOID;
+		}
+
+		if (!OidIsValid(targettype))
+			targettype = format == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+		/* Try to coerce to the target type. */
+		coerced = coerce_to_target_type(pstate, expr, exprtype,
+										targettype, -1,
+										COERCION_EXPLICIT,
+										COERCE_EXPLICIT_CAST,
+										location);
+
+		if (!coerced)
+		{
+			/* If coercion failed, use to_json()/to_jsonb() functions. */
+			FuncExpr   *fexpr;
+			Oid			fnoid;
+
+			if (cast_is_needed)		/* only CAST is allowed */
+				ereport(ERROR,
+						(errcode(ERRCODE_CANNOT_COERCE),
+						 errmsg("cannot cast type %s to %s",
+								format_type_be(exprtype),
+								format_type_be(targettype)),
+								parser_errposition(pstate, location)));
+
+			fnoid = targettype == JSONOID ? F_TO_JSON : F_TO_JSONB;
+			fexpr = makeFuncExpr(fnoid, targettype, list_make1(expr),
+								 InvalidOid, InvalidOid, COERCE_EXPLICIT_CALL);
+
+			fexpr->location = location;
+
+			coerced = (Node *) fexpr;
+		}
+
+		if (coerced == orig)
+			expr = rawexpr;
+		else
+		{
+			ve = copyObject(ve);
+			ve->raw_expr = (Expr *) rawexpr;
+			ve->formatted_expr = (Expr *) coerced;
+
+			expr = (Node *) ve;
+		}
+	}
+
+	return expr;
+}
+
+/*
+ * Transform JSON value expression using FORMAT JSON by default.
+ */
+static Node *
+transformJsonValueExpr(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_JSON, false,
+									 InvalidOid);
+}
+
+/*
+ * Transform JSON value expression using unspecified format by default.
+ */
+static Node *
+transformJsonValueExprDefault(ParseState *pstate, JsonValueExpr *jve)
+{
+	return transformJsonValueExprExt(pstate, jve, JS_FORMAT_DEFAULT, false,
+									 InvalidOid);
+}
+
+/*
+ * Checks specified output format for its applicability to the target type.
+ */
+static void
+checkJsonOutputFormat(ParseState *pstate, const JsonFormat *format,
+					  Oid targettype, bool allow_format_for_non_strings)
+{
+	if (!allow_format_for_non_strings &&
+		format->format_type != JS_FORMAT_DEFAULT &&
+		(targettype != BYTEAOID &&
+		 targettype != JSONOID &&
+		 targettype != JSONBOID))
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(targettype, &typcategory, &typispreferred);
+
+		if (typcategory != TYPCATEGORY_STRING)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON format with non-string output types")));
+	}
+
+	if (format->format_type == JS_FORMAT_JSON)
+	{
+		JsonEncoding enc = format->encoding != JS_ENC_DEFAULT ?
+						   format->encoding : JS_ENC_UTF8;
+
+		if (targettype != BYTEAOID &&
+			format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot set JSON encoding for non-bytea output types")));
+
+		if (enc != JS_ENC_UTF8)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("unsupported JSON encoding"),
+					 errhint("only UTF8 JSON encoding is supported"),
+					 parser_errposition(pstate, format->location)));
+	}
+}
+
+/*
+ * Transform JSON output clause.
+ *
+ * Assigns target type oid and modifier.
+ * Assigns default format or checks specified format for its applicability to
+ * the target type.
+ */
+static JsonReturning *
+transformJsonOutput(ParseState *pstate, const JsonOutput *output,
+					bool allow_format)
+{
+	JsonReturning *ret;
+
+	/* if output clause is not specified, make default clause value */
+	if (!output)
+	{
+		ret = makeNode(JsonReturning);
+
+		ret->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+		ret->typid = InvalidOid;
+		ret->typmod = -1;
+
+		return ret;
+	}
+
+	ret = copyObject(output->returning);
+
+	typenameTypeIdAndMod(pstate, output->typeName, &ret->typid, &ret->typmod);
+
+	if (output->typeName->setof)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("returning SETOF types is not supported in SQL/JSON functions")));
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		/* assign JSONB format when returning jsonb, or JSON format otherwise */
+		ret->format->format_type =
+			ret->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+	else
+		checkJsonOutputFormat(pstate, ret->format, ret->typid, allow_format);
+
+	return ret;
+}
+
+/*
+ * Transform JSON output clause of JSON contructor functions.
+ *
+ * Derive RETURNING type, if not specified, from argument types.
+ */
+static JsonReturning *
+transformJsonConstructorOutput(ParseState *pstate, JsonOutput *output,
+							   List *args)
+{
+	JsonReturning *returning = transformJsonOutput(pstate, output, true);
+
+	if (!OidIsValid(returning->typid))
+	{
+		ListCell   *lc;
+		bool		have_json = false;
+		bool		have_jsonb = false;
+
+		foreach(lc, args)
+		{
+			Node	   *expr = lfirst(lc);
+			Oid			typid = exprType(expr);
+
+			have_json |= typid == JSONOID;
+			have_jsonb |= typid == JSONBOID;
+
+			if (have_jsonb)
+				break;
+		}
+
+		if (have_jsonb)
+		{
+			returning->typid = JSONBOID;
+			returning->format->format_type = JS_FORMAT_JSONB;
+		}
+		else
+		{
+			/* Note: this includes the have_json case */
+			
+			/* XXX TEXT is default by the standard, but we return JSON */
+			returning->typid = JSONOID;
+			returning->format->format_type = JS_FORMAT_JSON;
+		}
+
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Coerce json[b]-valued function expression to the output type.
+ */
+static Node *
+coerceJsonFuncExpr(ParseState *pstate, Node *expr,
+				   const JsonReturning *returning, bool report_error)
+{
+	Node	   *res;
+	int			location;
+	Oid			exprtype = exprType(expr);
+
+	/* if output type is not specified or equals to function type, return */
+	if (!OidIsValid(returning->typid) || returning->typid == exprtype)
+		return expr;
+
+	location = exprLocation(expr);
+
+	if (location < 0)
+		location = returning ? returning->format->location : -1;
+
+	/* special case for RETURNING bytea FORMAT json */
+	if (returning->format->format_type == JS_FORMAT_JSON &&
+		returning->typid == BYTEAOID)
+	{
+		/* encode json text into bytea using pg_convert_to() */
+		Node	   *texpr = coerce_to_specific_type(pstate, expr, TEXTOID,
+													"JSON_FUNCTION");
+		Const	   *enc = getJsonEncodingConst(returning->format);
+		FuncExpr   *fexpr = makeFuncExpr(F_CONVERT_TO, BYTEAOID,
+										 list_make2(texpr, enc),
+										 InvalidOid, InvalidOid,
+										 COERCE_EXPLICIT_CALL);
+		fexpr->location = location;
+
+		return (Node *) fexpr;
+	}
+
+	/* try to coerce expression to the output type */
+	res = coerce_to_target_type(pstate, expr, exprtype,
+								returning->typid, returning->typmod,
+								/* XXX throwing errors when casting to char(N) */
+								COERCION_EXPLICIT,
+								COERCE_EXPLICIT_CAST,
+								location);
+
+	if (!res && report_error)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(returning->typid)),
+				 parser_coercion_errposition(pstate, location, expr)));
+
+	return res;
+}
+
+static Node *
+makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
+						List *args, Expr *fexpr, JsonReturning *returning,
+						bool unique, bool absent_on_null, int location)
+{
+	JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
+	Node	   *placeholder;
+	Node	   *coercion;
+	Oid			intermediate_typid =
+		returning->format->format_type == JS_FORMAT_JSONB ? JSONBOID : JSONOID;
+
+	jsctor->args = args;
+	jsctor->func = fexpr;
+	jsctor->type = type;
+	jsctor->returning = returning;
+	jsctor->unique = unique;
+	jsctor->absent_on_null = absent_on_null;
+	jsctor->location = location;
+
+	if (fexpr)
+		placeholder = makeCaseTestExpr((Node *) fexpr);
+	else
+	{
+		CaseTestExpr *cte = makeNode(CaseTestExpr);
+
+		cte->typeId = intermediate_typid;
+		cte->typeMod = -1;
+		cte->collation = InvalidOid;
+
+		placeholder = (Node *) cte;
+	}
+
+	coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
+
+	if (coercion != placeholder)
+		jsctor->coercion = (Expr *) coercion;
+
+	return (Node *) jsctor;
+}
+
+/*
+ * Transform JSON_OBJECT() constructor.
+ *
+ * JSON_OBJECT() is transformed into json[b]_build_object[_ext]() call
+ * depending on the output JSON format. The first two arguments of
+ * json[b]_build_object_ext() are absent_on_null and check_key_uniqueness.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonObjectConstructor(ParseState *pstate, JsonObjectConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform key-value pairs, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append key-value arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonKeyValue *kv = castNode(JsonKeyValue, lfirst(lc));
+			Node	   *key = transformExprRecurse(pstate, (Node *) kv->key);
+			Node	   *val = transformJsonValueExprDefault(pstate, kv->value);
+
+			args = lappend(args, key);
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_OBJECT, args, NULL,
+								   returning, ctor->unique,
+								   ctor->absent_on_null, ctor->location);
+}
+
+/*
+ * Transform JSON_ARRAY(query [FORMAT] [RETURNING] [ON NULL]) into
+ *  (SELECT  JSON_ARRAYAGG(a  [FORMAT] [RETURNING] [ON NULL]) FROM (query) q(a))
+ */
+static Node *
+transformJsonArrayQueryConstructor(ParseState *pstate,
+								   JsonArrayQueryConstructor *ctor)
+{
+	SubLink	   *sublink = makeNode(SubLink);
+	SelectStmt *select = makeNode(SelectStmt);
+	RangeSubselect *range = makeNode(RangeSubselect);
+	Alias	   *alias = makeNode(Alias);
+	ResTarget  *target = makeNode(ResTarget);
+	JsonArrayAgg *agg = makeNode(JsonArrayAgg);
+	ColumnRef  *colref = makeNode(ColumnRef);
+	Query	   *query;
+	ParseState *qpstate;
+
+	/* Transform query only for counting target list entries. */
+	qpstate = make_parsestate(pstate);
+
+	query = transformStmt(qpstate, ctor->query);
+
+	if (count_nonjunk_tlist_entries(query->targetList) != 1)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("subquery must return only one column"),
+				 parser_errposition(pstate, ctor->location)));
+
+	free_parsestate(qpstate);
+
+	colref->fields = list_make2(makeString(pstrdup("q")),
+								makeString(pstrdup("a")));
+	colref->location = ctor->location;
+
+	agg->arg = makeJsonValueExpr((Expr *) colref, ctor->format);
+	agg->absent_on_null = ctor->absent_on_null;
+	agg->constructor = makeNode(JsonAggConstructor);
+	agg->constructor->agg_order = NIL;
+	agg->constructor->output = ctor->output;
+	agg->constructor->location = ctor->location;
+
+	target->name = NULL;
+	target->indirection = NIL;
+	target->val = (Node *) agg;
+	target->location = ctor->location;
+
+	alias->aliasname = pstrdup("q");
+	alias->colnames = list_make1(makeString(pstrdup("a")));
+
+	range->lateral = false;
+	range->subquery = ctor->query;
+	range->alias = alias;
+
+	select->targetList = list_make1(target);
+	select->fromClause = list_make1(range);
+
+	sublink->subLinkType = EXPR_SUBLINK;
+	sublink->subLinkId = 0;
+	sublink->testexpr = NULL;
+	sublink->operName = NIL;
+	sublink->subselect = (Node *) select;
+	sublink->location = ctor->location;
+
+	return transformExprRecurse(pstate, (Node *) sublink);
+}
+
+/*
+ * Common code for JSON_OBJECTAGG and JSON_ARRAYAGG transformation.
+ */
+static Node *
+transformJsonAggConstructor(ParseState *pstate, JsonAggConstructor *agg_ctor,
+							JsonReturning *returning, List *args,
+							const char *aggfn, Oid aggtype,
+							JsonConstructorType ctor_type,
+							bool unique, bool absent_on_null)
+{
+	Oid			aggfnoid;
+	Node	   *node;
+	Expr	   *aggfilter = agg_ctor->agg_filter ? (Expr *)
+		transformWhereClause(pstate, agg_ctor->agg_filter,
+							 EXPR_KIND_FILTER, "FILTER") : NULL;
+
+	aggfnoid = DatumGetInt32(DirectFunctionCall1(regprocin,
+												 CStringGetDatum(aggfn)));
+
+	if (agg_ctor->over)
+	{
+		/* window function */
+		WindowFunc *wfunc = makeNode(WindowFunc);
+
+		wfunc->winfnoid = aggfnoid;
+		wfunc->wintype = aggtype;
+		/* wincollid and inputcollid will be set by parse_collate.c */
+		wfunc->args = args;
+		/* winref will be set by transformWindowFuncCall */
+		wfunc->winstar = false;
+		wfunc->winagg = true;
+		wfunc->aggfilter = aggfilter;
+		wfunc->location = agg_ctor->location;
+
+		/*
+		 * ordered aggs not allowed in windows yet
+		 */
+		if (agg_ctor->agg_order != NIL)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("aggregate ORDER BY is not implemented for window functions"),
+					 parser_errposition(pstate, agg_ctor->location)));
+
+		/* parse_agg.c does additional window-func-specific processing */
+		transformWindowFuncCall(pstate, wfunc, agg_ctor->over);
+
+		node = (Node *) wfunc;
+	}
+	else
+	{
+		Aggref	   *aggref = makeNode(Aggref);
+
+		aggref->aggfnoid = aggfnoid;
+		aggref->aggtype = aggtype;
+
+		/* aggcollid and inputcollid will be set by parse_collate.c */
+		aggref->aggtranstype = InvalidOid;		/* will be set by planner */
+		/* aggargtypes will be set by transformAggregateCall */
+		/* aggdirectargs and args will be set by transformAggregateCall */
+		/* aggorder and aggdistinct will be set by transformAggregateCall */
+		aggref->aggfilter = aggfilter;
+		aggref->aggstar = false;
+		aggref->aggvariadic = false;
+		aggref->aggkind = AGGKIND_NORMAL;
+		/* agglevelsup will be set by transformAggregateCall */
+		aggref->aggsplit = AGGSPLIT_SIMPLE;		/* planner might change this */
+		aggref->location = agg_ctor->location;
+
+		transformAggregateCall(pstate, aggref, args, agg_ctor->agg_order, false);
+
+		node = (Node *) aggref;
+	}
+
+	return makeJsonConstructorExpr(pstate, ctor_type, NIL, (Expr *) node,
+								   returning, unique, absent_on_null,
+								   agg_ctor->location);
+}
+
+/*
+ * Transform JSON_OBJECTAGG() aggregate function.
+ *
+ * JSON_OBJECTAGG() is transformed into
+ * json[b]_objectagg(key, value, absent_on_null, check_unique) call depending on
+ * the output JSON format.  Then the function call result is coerced to the
+ * target output type.
+ */
+static Node *
+transformJsonObjectAgg(ParseState *pstate, JsonObjectAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *key;
+	Node	   *val;
+	List	   *args;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	key = transformExprRecurse(pstate, (Node *) agg->arg->key);
+	val = transformJsonValueExprDefault(pstate, agg->arg->value);
+	args = list_make2(key, val);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   args);
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique_strict"; /* F_JSONB_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg_strict"; /* F_JSONB_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.jsonb_object_agg_unique"; /* F_JSONB_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.jsonb_object_agg"; /* F_JSONB_OBJECT_AGG */
+
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		if (agg->absent_on_null)
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique_strict"; /* F_JSON_OBJECT_AGG_UNIQUE_STRICT */
+			else
+				aggfnname = "pg_catalog.json_object_agg_strict"; /* F_JSON_OBJECT_AGG_STRICT */
+		else
+			if (agg->unique)
+				aggfnname = "pg_catalog.json_object_agg_unique"; /* F_JSON_OBJECT_AGG_UNIQUE */
+			else
+				aggfnname = "pg_catalog.json_object_agg"; /* F_JSON_OBJECT_AGG */
+
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   args, aggfnname, aggtype,
+									   JSCTOR_JSON_OBJECTAGG,
+									   agg->unique, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAYAGG() aggregate function.
+ *
+ * JSON_ARRAYAGG() is transformed into json[b]_agg[_strict]() call depending
+ * on the output JSON format and absent_on_null.  Then the function call result
+ * is coerced to the target output type.
+ */
+static Node *
+transformJsonArrayAgg(ParseState *pstate, JsonArrayAgg *agg)
+{
+	JsonReturning *returning;
+	Node	   *arg;
+	const char *aggfnname;
+	Oid			aggtype;
+
+	arg = transformJsonValueExprDefault(pstate, agg->arg);
+
+	returning = transformJsonConstructorOutput(pstate, agg->constructor->output,
+											   list_make1(arg));
+
+	if (returning->format->format_type == JS_FORMAT_JSONB)
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.jsonb_agg_strict" : "pg_catalog.jsonb_agg";
+		aggtype = JSONBOID;
+	}
+	else
+	{
+		aggfnname = agg->absent_on_null ?
+			"pg_catalog.json_agg_strict" : "pg_catalog.json_agg";
+		aggtype = JSONOID;
+	}
+
+	return transformJsonAggConstructor(pstate, agg->constructor, returning,
+									   list_make1(arg), aggfnname, aggtype,
+									   JSCTOR_JSON_ARRAYAGG,
+									   false, agg->absent_on_null);
+}
+
+/*
+ * Transform JSON_ARRAY() constructor.
+ *
+ * JSON_ARRAY() is transformed into json[b]_build_array[_ext]() call
+ * depending on the output JSON format. The first argument of
+ * json[b]_build_array_ext() is absent_on_null.
+ *
+ * Then function call result is coerced to the target type.
+ */
+static Node *
+transformJsonArrayConstructor(ParseState *pstate, JsonArrayConstructor *ctor)
+{
+	JsonReturning *returning;
+	List	   *args = NIL;
+
+	/* transform element expressions, if any */
+	if (ctor->exprs)
+	{
+		ListCell   *lc;
+
+		/* transform and append element arguments */
+		foreach(lc, ctor->exprs)
+		{
+			JsonValueExpr *jsval = castNode(JsonValueExpr, lfirst(lc));
+			Node	   *val = transformJsonValueExprDefault(pstate, jsval);
+
+			args = lappend(args, val);
+		}
+	}
+
+	returning = transformJsonConstructorOutput(pstate, ctor->output, args);
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_ARRAY, args, NULL,
+								   returning, false, ctor->absent_on_null,
+								   ctor->location);
+}
+
+static Node *
+transformJsonParseArg(ParseState *pstate, Node *jsexpr, JsonFormat *format,
+					  Oid *exprtype)
+{
+	Node	   *raw_expr = transformExprRecurse(pstate, jsexpr);
+	Node	   *expr = raw_expr;
+
+	*exprtype = exprType(expr);
+
+	/* prepare input document */
+	if (*exprtype == BYTEAOID)
+	{
+		JsonValueExpr *jve;
+
+		expr = makeCaseTestExpr(raw_expr);
+		expr = makeJsonByteaToTextConversion(expr, format, exprLocation(expr));
+		*exprtype = TEXTOID;
+
+		jve = makeJsonValueExpr((Expr *) raw_expr, format);
+
+		jve->formatted_expr = (Expr *) expr;
+		expr = (Node *) jve;
+	}
+	else
+	{
+		char		typcategory;
+		bool		typispreferred;
+
+		get_type_category_preferred(*exprtype, &typcategory, &typispreferred);
+
+		if (*exprtype == UNKNOWNOID || typcategory == TYPCATEGORY_STRING)
+		{
+			expr = coerce_to_target_type(pstate, (Node *) expr, *exprtype,
+										 TEXTOID, -1,
+										 COERCION_IMPLICIT,
+										 COERCE_IMPLICIT_CAST, -1);
+			*exprtype = TEXTOID;
+		}
+
+		if (format->encoding != JS_ENC_DEFAULT)
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 parser_errposition(pstate, format->location),
+					 errmsg("cannot use JSON FORMAT ENCODING clause for non-bytea input types")));
+	}
+
+	return expr;
+}
+
+/*
+ * Transform IS JSON predicate into
+ * json[b]_is_valid(json, value_type [, check_key_uniqueness]) call.
+ */
+static Node *
+transformJsonIsPredicate(ParseState *pstate, JsonIsPredicate *pred)
+{
+	Oid			exprtype;
+	Node	   *expr = transformJsonParseArg(pstate, pred->expr, pred->format,
+											 &exprtype);
+
+	/* make resulting expression */
+	if (exprtype != TEXTOID && exprtype != JSONOID && exprtype != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("cannot use type %s in IS JSON predicate",
+						format_type_be(exprtype))));
+
+	return makeJsonIsPredicate(expr, NULL, pred->value_type,
+							   pred->unique_keys, pred->location);
+}
+
+/*
+ * Transform a JSON PASSING clause.
+ */
+static void
+transformJsonPassingArgs(ParseState *pstate, JsonFormatType format, List *args,
+						 List **passing_values, List **passing_names)
+{
+	ListCell   *lc;
+
+	*passing_values = NIL;
+	*passing_names = NIL;
+
+	foreach(lc, args)
+	{
+		JsonArgument *arg = castNode(JsonArgument, lfirst(lc));
+		Node	   *expr = transformJsonValueExprExt(pstate, arg->val,
+													 format, true, InvalidOid);
+
+		assign_expr_collations(pstate, expr);
+
+		*passing_values = lappend(*passing_values, expr);
+		*passing_names = lappend(*passing_names, makeString(arg->name));
+	}
+}
+
+/*
+ * Transform a JSON BEHAVIOR clause.
+ */
+static JsonBehavior *
+transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
+					  JsonBehaviorType default_behavior)
+{
+	JsonBehaviorType behavior_type;
+	Node	   *default_expr;
+
+	behavior_type = behavior ? behavior->btype : default_behavior;
+	default_expr = behavior_type != JSON_BEHAVIOR_DEFAULT ? NULL :
+		transformExprRecurse(pstate, behavior->default_expr);
+
+	return makeJsonBehavior(behavior_type, default_expr);
+}
+
+/*
+ * Common code for JSON_VALUE, JSON_QUERY, JSON_EXISTS transformation
+ * into a JsonExpr node.
+ */
+static JsonExpr *
+transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = makeNode(JsonExpr);
+	Node	   *pathspec;
+	JsonFormatType format;
+
+	if (func->common->pathname)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("JSON_TABLE path name is not allowed here"),
+				 parser_errposition(pstate, func->location)));
+
+	jsexpr->location = func->location;
+	jsexpr->op = func->op;
+	jsexpr->formatted_expr = transformJsonValueExpr(pstate, func->common->expr);
+
+	assign_expr_collations(pstate, jsexpr->formatted_expr);
+
+	/* format is determined by context item type */
+	format = exprType(jsexpr->formatted_expr) == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON;
+
+	jsexpr->result_coercion = NULL;
+	jsexpr->omit_quotes = false;
+
+	jsexpr->format = func->common->expr->format;
+
+	pathspec = transformExprRecurse(pstate, func->common->pathspec);
+
+	jsexpr->path_spec =
+		coerce_to_target_type(pstate, pathspec, exprType(pathspec),
+							  JSONPATHOID, -1,
+							  COERCION_EXPLICIT, COERCE_IMPLICIT_CAST,
+							  exprLocation(pathspec));
+	if (!jsexpr->path_spec)
+		ereport(ERROR,
+				(errcode(ERRCODE_DATATYPE_MISMATCH),
+				 errmsg("JSON path expression must be type %s, not type %s",
+						"jsonpath", format_type_be(exprType(pathspec))),
+				 parser_errposition(pstate, exprLocation(pathspec))));
+
+	/* transform and coerce to json[b] passing arguments */
+	transformJsonPassingArgs(pstate, format, func->common->passing,
+							 &jsexpr->passing_values, &jsexpr->passing_names);
+
+	if (func->op != IS_JSON_EXISTS)
+		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
+												 JSON_BEHAVIOR_NULL);
+
+	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
+											 func->op == IS_JSON_EXISTS ?
+											 JSON_BEHAVIOR_FALSE :
+											 JSON_BEHAVIOR_NULL);
+
+	return jsexpr;
+}
+
+/*
+ * Assign default JSON returning type from the specified format or from
+ * the context item type.
+ */
+static void
+assignDefaultJsonReturningType(Node *context_item, JsonFormat *context_format,
+							   JsonReturning *ret)
+{
+	bool		is_jsonb;
+
+	ret->format = copyObject(context_format);
+
+	if (ret->format->format_type == JS_FORMAT_DEFAULT)
+		is_jsonb = exprType(context_item) == JSONBOID;
+	else
+		is_jsonb = ret->format->format_type == JS_FORMAT_JSONB;
+
+	ret->typid = is_jsonb ? JSONBOID : JSONOID;
+	ret->typmod = -1;
+}
+
+/*
+ * Try to coerce expression to the output type or
+ * use json_populate_type() for composite, array and domain types or
+ * use coercion via I/O.
+ */
+static JsonCoercion *
+coerceJsonExpr(ParseState *pstate, Node *expr, const JsonReturning *returning)
+{
+	char		typtype;
+	JsonCoercion *coercion = makeNode(JsonCoercion);
+
+	coercion->expr = coerceJsonFuncExpr(pstate, expr, returning, false);
+
+	if (coercion->expr)
+	{
+		if (coercion->expr == expr)
+			coercion->expr = NULL;
+
+		return coercion;
+	}
+
+	typtype = get_typtype(returning->typid);
+
+	if (returning->typid == RECORDOID ||
+		typtype == TYPTYPE_COMPOSITE ||
+		typtype == TYPTYPE_DOMAIN ||
+		type_is_array(returning->typid))
+		coercion->via_populate = true;
+	else
+		coercion->via_io = true;
+
+	return coercion;
+}
+
+/*
+ * Transform a JSON output clause of JSON_VALUE and JSON_QUERY.
+ */
+static void
+transformJsonFuncExprOutput(ParseState *pstate,	JsonFuncExpr *func,
+							JsonExpr *jsexpr)
+{
+	Node	   *expr = jsexpr->formatted_expr;
+
+	jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+	/* JSON_VALUE returns text by default */
+	if (func->op == IS_JSON_VALUE && !OidIsValid(jsexpr->returning->typid))
+	{
+		jsexpr->returning->typid = TEXTOID;
+		jsexpr->returning->typmod = -1;
+	}
+
+	if (OidIsValid(jsexpr->returning->typid))
+	{
+		JsonReturning ret;
+
+		if (func->op == IS_JSON_VALUE &&
+			jsexpr->returning->typid != JSONOID &&
+			jsexpr->returning->typid != JSONBOID)
+		{
+			/* Forced coercion via I/O for JSON_VALUE for non-JSON types */
+			jsexpr->result_coercion = makeNode(JsonCoercion);
+			jsexpr->result_coercion->expr = NULL;
+			jsexpr->result_coercion->via_io = true;
+			return;
+		}
+
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format, &ret);
+
+		if (ret.typid != jsexpr->returning->typid ||
+			ret.typmod != jsexpr->returning->typmod)
+		{
+			Node	   *placeholder = makeCaseTestExpr(expr);
+
+			Assert(((CaseTestExpr *) placeholder)->typeId == ret.typid);
+			Assert(((CaseTestExpr *) placeholder)->typeMod == ret.typmod);
+
+			jsexpr->result_coercion = coerceJsonExpr(pstate, placeholder,
+													 jsexpr->returning);
+		}
+	}
+	else
+		assignDefaultJsonReturningType(jsexpr->formatted_expr, jsexpr->format,
+									   jsexpr->returning);
+}
+
+/*
+ * Coerce a expression in JSON DEFAULT behavior to the target output type.
+ */
+static Node *
+coerceDefaultJsonExpr(ParseState *pstate, JsonExpr *jsexpr, Node *defexpr)
+{
+	int			location;
+	Oid			exprtype;
+
+	if (!defexpr)
+		return NULL;
+
+	exprtype = exprType(defexpr);
+	location = exprLocation(defexpr);
+
+	if (location < 0)
+		location = jsexpr->location;
+
+	defexpr = coerce_to_target_type(pstate,
+									defexpr,
+									exprtype,
+									jsexpr->returning->typid,
+									jsexpr->returning->typmod,
+									COERCION_EXPLICIT,
+									COERCE_IMPLICIT_CAST,
+									location);
+
+	if (!defexpr)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast DEFAULT expression type %s to %s",
+						format_type_be(exprtype),
+						format_type_be(jsexpr->returning->typid)),
+				 parser_errposition(pstate, location)));
+
+	return defexpr;
+}
+
+/*
+ * Initialize SQL/JSON item coercion from the SQL type "typid" to the target
+ * "returning" type.
+ */
+static JsonCoercion *
+initJsonItemCoercion(ParseState *pstate, Oid typid,
+					 const JsonReturning *returning)
+{
+	Node	   *expr;
+
+	if (typid == UNKNOWNOID)
+	{
+		expr = (Node *) makeNullConst(UNKNOWNOID, -1, InvalidOid);
+	}
+	else
+	{
+		CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+
+		placeholder->typeId = typid;
+		placeholder->typeMod = -1;
+		placeholder->collation = InvalidOid;
+
+		expr = (Node *) placeholder;
+	}
+
+	return coerceJsonExpr(pstate, expr, returning);
+}
+
+static void
+initJsonItemCoercions(ParseState *pstate, JsonItemCoercions *coercions,
+					  const JsonReturning *returning, Oid contextItemTypeId)
+{
+	struct
+	{
+		JsonCoercion **coercion;
+		Oid			typid;
+	}		   *p,
+				coercionTypids[] =
+				{
+					{ &coercions->null, UNKNOWNOID },
+					{ &coercions->string, TEXTOID },
+					{ &coercions->numeric, NUMERICOID },
+					{ &coercions->boolean, BOOLOID },
+					{ &coercions->date, DATEOID },
+					{ &coercions->time, TIMEOID },
+					{ &coercions->timetz, TIMETZOID },
+					{ &coercions->timestamp, TIMESTAMPOID },
+					{ &coercions->timestamptz, TIMESTAMPTZOID },
+					{ &coercions->composite, contextItemTypeId },
+					{ NULL, InvalidOid }
+				};
+
+	for (p = coercionTypids; p->coercion; p++)
+		*p->coercion = initJsonItemCoercion(pstate, p->typid, returning);
+}
+
+/*
+ * Transform JSON_VALUE, JSON_QUERY, JSON_EXISTS functions into a JsonExpr node.
+ */
+static Node *
+transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
+{
+	JsonExpr   *jsexpr = transformJsonExprCommon(pstate, func);
+	const char *func_name = NULL;
+	Node	   *contextItemExpr = jsexpr->formatted_expr;
+
+	switch (func->op)
+	{
+		case IS_JSON_VALUE:
+			func_name = "JSON_VALUE";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->coercions = makeNode(JsonItemCoercions);
+			initJsonItemCoercions(pstate, jsexpr->coercions, jsexpr->returning,
+								  exprType(contextItemExpr));
+
+			break;
+
+		case IS_JSON_QUERY:
+			func_name = "JSON_QUERY";
+
+			transformJsonFuncExprOutput(pstate, func, jsexpr);
+
+			jsexpr->on_empty->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_empty->default_expr);
+
+			jsexpr->on_error->default_expr =
+				coerceDefaultJsonExpr(pstate, jsexpr,
+									  jsexpr->on_error->default_expr);
+
+			jsexpr->wrapper = func->wrapper;
+			jsexpr->omit_quotes = func->omit_quotes;
+
+			break;
+
+		case IS_JSON_EXISTS:
+			func_name = "JSON_EXISTS";
+
+			jsexpr->returning = transformJsonOutput(pstate, func->output, false);
+
+			jsexpr->returning->format->format_type = JS_FORMAT_DEFAULT;
+			jsexpr->returning->format->encoding = JS_ENC_DEFAULT;
+
+			if (!OidIsValid(jsexpr->returning->typid))
+			{
+				jsexpr->returning->typid = BOOLOID;
+				jsexpr->returning->typmod = -1;
+			}
+			else if (jsexpr->returning->typid != BOOLOID)
+			{
+				CaseTestExpr *placeholder = makeNode(CaseTestExpr);
+				int			location = exprLocation((Node *) jsexpr);
+
+				placeholder->typeId = BOOLOID;
+				placeholder->typeMod = -1;
+				placeholder->collation = InvalidOid;
+
+				jsexpr->result_coercion = makeNode(JsonCoercion);
+				jsexpr->result_coercion->expr =
+					coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
+										  jsexpr->returning->typid,
+										  jsexpr->returning->typmod,
+										  COERCION_EXPLICIT,
+										  COERCE_IMPLICIT_CAST,
+										  location);
+
+				if (!jsexpr->result_coercion->expr)
+					ereport(ERROR,
+							(errcode(ERRCODE_CANNOT_COERCE),
+							 errmsg("cannot cast type %s to %s",
+									format_type_be(BOOLOID),
+									format_type_be(jsexpr->returning->typid)),
+							 parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
+
+				if (jsexpr->result_coercion->expr == (Node *) placeholder)
+					jsexpr->result_coercion->expr = NULL;
+			}
+			break;
+	}
+
+	if (exprType(contextItemExpr) != JSONBOID)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("%s() is not yet implemented for json type", func_name),
+				 parser_errposition(pstate, func->location)));
+
+	return (Node *) jsexpr;
+}
+
+static JsonReturning *
+transformJsonConstructorRet(ParseState *pstate, JsonOutput *output, const char *fname)
+{
+	JsonReturning *returning;
+
+	if (output)
+	{
+		returning = transformJsonOutput(pstate, output, false);
+
+		Assert(OidIsValid(returning->typid));
+
+		if (returning->typid != JSONOID && returning->typid != JSONBOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use RETURNING type %s in %s",
+							format_type_be(returning->typid), fname),
+					 parser_errposition(pstate, output->typeName->location)));
+	}
+	else
+	{
+		Oid			targettype = JSONOID;
+		JsonFormatType format = JS_FORMAT_JSON;
+
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(format, JS_ENC_DEFAULT, -1);
+		returning->typid = targettype;
+		returning->typmod = -1;
+	}
+
+	return returning;
+}
+
+/*
+ * Transform a JSON() expression.
+ */
+static Node *
+transformJsonParseExpr(ParseState *pstate, JsonParseExpr *jsexpr)
+{
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON()");
+	Node	   *arg;
+
+	if (jsexpr->unique_keys)
+	{
+		/*
+		 * Coerce string argument to text and then to json[b] in the executor
+		 * node with key uniqueness check.
+		 */
+		JsonValueExpr *jve = jsexpr->expr;
+		Oid			arg_type;
+
+		arg = transformJsonParseArg(pstate, (Node *) jve->raw_expr, jve->format,
+									&arg_type);
+
+		if (arg_type != TEXTOID)
+			ereport(ERROR,
+					(errcode(ERRCODE_DATATYPE_MISMATCH),
+					 errmsg("cannot use non-string types with WITH UNIQUE KEYS clause"),
+					 parser_errposition(pstate, jsexpr->location)));
+	}
+	else
+	{
+		/*
+		 * Coerce argument to target type using CAST for compatibilty with PG
+		 * function-like CASTs.
+		 */
+		arg = transformJsonValueExprExt(pstate, jsexpr->expr, JS_FORMAT_JSON,
+										false, returning->typid);
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_PARSE, list_make1(arg), NULL,
+							returning, jsexpr->unique_keys, false,
+							jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SCALAR() expression.
+ */
+static Node *
+transformJsonScalarExpr(ParseState *pstate, JsonScalarExpr *jsexpr)
+{
+	Node	   *arg = transformExprRecurse(pstate, (Node *) jsexpr->expr);
+	JsonReturning *returning = transformJsonConstructorRet(pstate, jsexpr->output,
+													"JSON_SCALAR()");
+
+	if (exprType(arg) == UNKNOWNOID)
+		arg = coerce_to_specific_type(pstate, arg, TEXTOID, "JSON_SCALAR");
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SCALAR, list_make1(arg), NULL,
+							returning, false, false, jsexpr->location);
+}
+
+/*
+ * Transform a JSON_SERIALIZE() expression.
+ */
+static Node *
+transformJsonSerializeExpr(ParseState *pstate, JsonSerializeExpr *expr)
+{
+	Node	   *arg = transformJsonValueExpr(pstate, expr->expr);
+	JsonReturning *returning;
+
+	if (expr->output)
+		returning = transformJsonOutput(pstate, expr->output, true);
+	else
+	{
+		/* RETURNING TEXT FORMAT JSON is by default */
+		returning = makeNode(JsonReturning);
+		returning->format = makeJsonFormat(JS_FORMAT_JSON, JS_ENC_DEFAULT, -1);
+		returning->typid = TEXTOID;
+		returning->typmod = -1;
+	}
+
+	return makeJsonConstructorExpr(pstate, JSCTOR_JSON_SERIALIZE, list_make1(arg),
+							NULL, returning, false, false, expr->location);
+}
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 059eeb9e94..829c0f9497 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1957,6 +1957,43 @@ FigureColnameInternal(Node *node, char **name)
 		case T_XmlSerialize:
 			*name = "xmlserialize";
 			return 2;
+		case T_JsonParseExpr:
+			*name = "json";
+			return 2;
+		case T_JsonScalarExpr:
+			*name = "json_scalar";
+			return 2;
+		case T_JsonSerializeExpr:
+			*name = "json_serialize";
+			return 2;
+		case T_JsonObjectConstructor:
+			*name = "json_object";
+			return 2;
+		case T_JsonArrayConstructor:
+		case T_JsonArrayQueryConstructor:
+			*name = "json_array";
+			return 2;
+		case T_JsonObjectAgg:
+			*name = "json_objectagg";
+			return 2;
+		case T_JsonArrayAgg:
+			*name = "json_arrayagg";
+			return 2;
+		case T_JsonFuncExpr:
+			/* make SQL/JSON functions act like a regular function */
+			switch (((JsonFuncExpr *) node)->op)
+			{
+				case IS_JSON_QUERY:
+					*name = "json_query";
+					return 2;
+				case IS_JSON_VALUE:
+					*name = "json_value";
+					return 2;
+				case IS_JSON_EXISTS:
+					*name = "json_exists";
+					return 2;
+			}
+			break;
 		default:
 			break;
 	}
diff --git a/src/backend/parser/parser.c b/src/backend/parser/parser.c
index 50227cc098..eee0a29c08 100644
--- a/src/backend/parser/parser.c
+++ b/src/backend/parser/parser.c
@@ -150,6 +150,9 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 		case USCONST:
 			cur_token_length = strlen(yyextra->core_yy_extra.scanbuf + *llocp);
 			break;
+		case WITHOUT:
+			cur_token_length = 7;
+			break;
 		default:
 			return cur_token;
 	}
@@ -221,6 +224,19 @@ base_yylex(YYSTYPE *lvalp, YYLTYPE *llocp, core_yyscan_t yyscanner)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 
diff --git a/src/backend/utils/adt/format_type.c b/src/backend/utils/adt/format_type.c
index 2918fdbfb6..060fd7e183 100644
--- a/src/backend/utils/adt/format_type.c
+++ b/src/backend/utils/adt/format_type.c
@@ -294,6 +294,10 @@ format_type_extended(Oid type_oid, int32 typemod, bits16 flags)
 			else
 				buf = pstrdup("character varying");
 			break;
+
+		case JSONOID:
+			buf = pstrdup("json");
+			break;
 	}
 
 	if (buf == NULL)
diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c
index ed698f788d..ac74333be5 100644
--- a/src/backend/utils/adt/formatting.c
+++ b/src/backend/utils/adt/formatting.c
@@ -1023,11 +1023,6 @@ typedef struct NUMProc
 			   *L_currency_symbol;
 } NUMProc;
 
-/* Return flags for DCH_from_char() */
-#define DCH_DATED	0x01
-#define DCH_TIMED	0x02
-#define DCH_ZONED	0x04
-
 /* ----------
  * Functions
  * ----------
@@ -6672,3 +6667,43 @@ float8_to_char(PG_FUNCTION_ARGS)
 	NUM_TOCHAR_finish;
 	PG_RETURN_TEXT_P(result);
 }
+
+int
+datetime_format_flags(const char *fmt_str, bool *have_error)
+{
+	bool		incache;
+	int			fmt_len = strlen(fmt_str);
+	int			result;
+	FormatNode *format;
+
+	if (fmt_len > DCH_CACHE_SIZE)
+	{
+		/*
+		 * Allocate new memory if format picture is bigger than static cache
+		 * and do not use cache (call parser always)
+		 */
+		incache = false;
+
+		format = (FormatNode *) palloc((fmt_len + 1) * sizeof(FormatNode));
+
+		parse_format(format, fmt_str, DCH_keywords,
+					 DCH_suff, DCH_index, DCH_FLAG, NULL);
+	}
+	else
+	{
+		/*
+		 * Use cache buffers
+		 */
+		DCHCacheEntry *ent = DCH_cache_fetch(fmt_str, false);
+
+		incache = true;
+		format = ent->format;
+	}
+
+	result = DCH_datetime_type(format, have_error);
+
+	if (!incache)
+		pfree(format);
+
+	return result;
+}
diff --git a/src/backend/utils/adt/json.c b/src/backend/utils/adt/json.c
index 7879f342e6..492796eb83 100644
--- a/src/backend/utils/adt/json.c
+++ b/src/backend/utils/adt/json.c
@@ -13,7 +13,10 @@
  */
 #include "postgres.h"
 
+#include "access/hash.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "common/hashfn.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
@@ -27,20 +30,41 @@
 #include "utils/lsyscache.h"
 #include "utils/typcache.h"
 
-typedef enum					/* type categories for datum_to_json */
+/* Common context for key uniqueness check */
+typedef struct HTAB *JsonUniqueCheckState;	/* hash table for key names */
+
+/* Hash entry for JsonUniqueCheckState */
+typedef struct JsonUniqueHashEntry
+{
+	const char *key;
+	int			key_len;
+	int			object_id;
+} JsonUniqueHashEntry;
+
+/* Context for key uniqueness check in builder functions */
+typedef struct JsonUniqueBuilderState
+{
+	JsonUniqueCheckState check;	/* unique check */
+	StringInfoData skipped_keys;	/* skipped keys with NULL values */
+	MemoryContext mcxt;				/* context for saving skipped keys */
+} JsonUniqueBuilderState;
+
+/* Element of object stack for key uniqueness check during json parsing */
+typedef struct JsonUniqueStackEntry
 {
-	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONTYPE_TIMESTAMP,
-	JSONTYPE_TIMESTAMPTZ,
-	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
-	JSONTYPE_ARRAY,				/* array */
-	JSONTYPE_COMPOSITE,			/* composite */
-	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
-	JSONTYPE_OTHER				/* all else */
-} JsonTypeCategory;
+	struct JsonUniqueStackEntry *parent;
+	int			object_id;
+} JsonUniqueStackEntry;
+
+/* State for key uniqueness check during json parsing */
+typedef struct JsonUniqueParsingState
+{
+	JsonLexContext *lex;
+	JsonUniqueCheckState check;
+	JsonUniqueStackEntry *stack;
+	int			id_counter;
+	bool		unique;
+} JsonUniqueParsingState;
 
 typedef struct JsonAggState
 {
@@ -49,6 +73,7 @@ typedef struct JsonAggState
 	Oid			key_output_func;
 	JsonTypeCategory val_category;
 	Oid			val_output_func;
+	JsonUniqueBuilderState unique_check;
 } JsonAggState;
 
 static void composite_to_json(Datum composite, StringInfo result,
@@ -59,9 +84,6 @@ static void array_dim_to_json(StringInfo result, int dim, int ndims, int *dims,
 							  bool use_line_feeds);
 static void array_to_json_internal(Datum array, StringInfo result,
 								   bool use_line_feeds);
-static void json_categorize_type(Oid typoid,
-								 JsonTypeCategory *tcategory,
-								 Oid *outfuncoid);
 static void datum_to_json(Datum val, bool is_null, StringInfo result,
 						  JsonTypeCategory tcategory, Oid outfuncoid,
 						  bool key_scalar);
@@ -140,7 +162,7 @@ json_recv(PG_FUNCTION_ARGS)
  * output function OID.  If the returned category is JSONTYPE_CAST, we
  * return the OID of the type->JSON cast function instead.
  */
-static void
+void
 json_categorize_type(Oid typoid,
 					 JsonTypeCategory *tcategory,
 					 Oid *outfuncoid)
@@ -722,6 +744,48 @@ row_to_json_pretty(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
 }
 
+Datum
+to_json_worker(Datum val, JsonTypeCategory tcategory, Oid outfuncoid)
+{
+	StringInfo	result = makeStringInfo();
+
+	datum_to_json(val, false, result, tcategory, outfuncoid, false);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+bool
+to_json_is_immutable(Oid typoid)
+{
+	JsonTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	json_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONTYPE_BOOL:
+		case JSONTYPE_JSON:
+			return true;
+
+		case JSONTYPE_DATE:
+		case JSONTYPE_TIMESTAMP:
+		case JSONTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONTYPE_NUMERIC:
+		case JSONTYPE_CAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_json(anyvalue)
  */
@@ -730,7 +794,6 @@ to_json(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	StringInfo	result;
 	JsonTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -742,11 +805,7 @@ to_json(PG_FUNCTION_ARGS)
 	json_categorize_type(val_type,
 						 &tcategory, &outfuncoid);
 
-	result = makeStringInfo();
-
-	datum_to_json(val, false, result, tcategory, outfuncoid, false);
-
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	PG_RETURN_DATUM(to_json_worker(val, tcategory, outfuncoid));
 }
 
 /*
@@ -754,8 +813,8 @@ to_json(PG_FUNCTION_ARGS)
  *
  * aggregate input column as a json array value.
  */
-Datum
-json_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext aggcontext,
 				oldcontext;
@@ -795,9 +854,14 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
+	if (state->str->len > 1)
+		appendStringInfoString(state->str, ", ");
+
 	/* fast path for NULLs */
 	if (PG_ARGISNULL(1))
 	{
@@ -809,7 +873,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	val = PG_GETARG_DATUM(1);
 
 	/* add some whitespace if structured type and not first item */
-	if (!PG_ARGISNULL(0) &&
+	if (!PG_ARGISNULL(0) && state->str->len > 1 &&
 		(state->val_category == JSONTYPE_ARRAY ||
 		 state->val_category == JSONTYPE_COMPOSITE))
 	{
@@ -827,6 +891,25 @@ json_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+
+/*
+ * json_agg aggregate function
+ */
+Datum
+json_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * json_agg_strict aggregate function
+ */
+Datum
+json_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_agg_transfn_worker(fcinfo, true);
+}
+
 /*
  * json_agg final function
  */
@@ -850,18 +933,122 @@ json_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, "]"));
 }
 
+/* Functions implementing hash table for key uniqueness check */
+static uint32
+json_unique_hash(const void *key, Size keysize)
+{
+	const JsonUniqueHashEntry *entry = (JsonUniqueHashEntry *) key;
+	uint32		hash =  hash_bytes_uint32(entry->object_id);
+
+	hash ^= hash_bytes((const unsigned char *) entry->key, entry->key_len);
+
+	return DatumGetUInt32(hash);
+}
+
+static int
+json_unique_hash_match(const void *key1, const void *key2, Size keysize)
+{
+	const JsonUniqueHashEntry *entry1 = (const JsonUniqueHashEntry *) key1;
+	const JsonUniqueHashEntry *entry2 = (const JsonUniqueHashEntry *) key2;
+
+	if (entry1->object_id != entry2->object_id)
+		return entry1->object_id > entry2->object_id ? 1 : -1;
+
+	if (entry1->key_len != entry2->key_len)
+		return entry1->key_len > entry2->key_len ? 1 : -1;
+
+	return strncmp(entry1->key, entry2->key, entry1->key_len);
+}
+
+/* Functions implementing object key uniqueness check */
+static void
+json_unique_check_init(JsonUniqueCheckState *cxt)
+{
+	HASHCTL		ctl;
+
+	memset(&ctl, 0, sizeof(ctl));
+	ctl.keysize = sizeof(JsonUniqueHashEntry);
+	ctl.entrysize = sizeof(JsonUniqueHashEntry);
+	ctl.hcxt = CurrentMemoryContext;
+	ctl.hash = json_unique_hash;
+	ctl.match = json_unique_hash_match;
+
+	*cxt = hash_create("json object hashtable",
+					   32,
+					   &ctl,
+					   HASH_ELEM | HASH_CONTEXT | HASH_FUNCTION | HASH_COMPARE);
+}
+
+static void
+json_unique_check_free(JsonUniqueCheckState *cxt)
+{
+	hash_destroy(*cxt);
+}
+
+static bool
+json_unique_check_key(JsonUniqueCheckState *cxt, const char *key, int object_id)
+{
+	JsonUniqueHashEntry entry;
+	bool		found;
+
+	entry.key = key;
+	entry.key_len = strlen(key);
+	entry.object_id = object_id;
+
+	(void) hash_search(*cxt, &entry, HASH_ENTER, &found);
+
+	return !found;
+}
+
+static void
+json_unique_builder_init(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_init(&cxt->check);
+	cxt->mcxt = CurrentMemoryContext;
+	cxt->skipped_keys.data = NULL;
+}
+
+static void
+json_unique_builder_free(JsonUniqueBuilderState *cxt)
+{
+	json_unique_check_free(&cxt->check);
+
+	if (cxt->skipped_keys.data)
+		pfree(cxt->skipped_keys.data);
+}
+
+/* On-demand initialization of skipped_keys StringInfo structure */
+static StringInfo
+json_unique_builder_get_skipped_keys(JsonUniqueBuilderState *cxt)
+{
+	StringInfo	out = &cxt->skipped_keys;
+
+	if (!out->data)
+	{
+		MemoryContext oldcxt = MemoryContextSwitchTo(cxt->mcxt);
+		initStringInfo(out);
+		MemoryContextSwitchTo(oldcxt);
+	}
+
+	return out;
+}
+
 /*
  * json_object_agg transition function.
  *
  * aggregate two input columns as a single json object value.
  */
-Datum
-json_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+json_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+							   bool absent_on_null, bool unique_keys)
 {
 	MemoryContext aggcontext,
 				oldcontext;
 	JsonAggState *state;
+	StringInfo	out;
 	Datum		arg;
+	bool		skip;
+	int			key_offset;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -882,6 +1069,10 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 		oldcontext = MemoryContextSwitchTo(aggcontext);
 		state = (JsonAggState *) palloc(sizeof(JsonAggState));
 		state->str = makeStringInfo();
+		if (unique_keys)
+			json_unique_builder_init(&state->unique_check);
+		else
+			memset(&state->unique_check, 0, sizeof(state->unique_check));
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -909,7 +1100,6 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	else
 	{
 		state = (JsonAggState *) PG_GETARG_POINTER(0);
-		appendStringInfoString(state->str, ", ");
 	}
 
 	/*
@@ -925,11 +1115,49 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/* Skip null values if absent_on_null */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip)
+	{
+		/* If key uniqueness check is needed we must save skipped keys */
+		if (!unique_keys)
+			PG_RETURN_POINTER(state);
+
+		out = json_unique_builder_get_skipped_keys(&state->unique_check);
+	}
+	else
+	{
+		out = state->str;
+
+		/*
+		 * Append comma delimiter only if we have already outputted some fields
+		 * after the initial string "{ ".
+		 */
+		if (out->len > 2)
+			appendStringInfoString(out, ", ");
+	}
+
 	arg = PG_GETARG_DATUM(1);
 
-	datum_to_json(arg, false, state->str, state->key_category,
+	key_offset = out->len;
+
+	datum_to_json(arg, false, out, state->key_category,
 				  state->key_output_func, true);
 
+	if (unique_keys)
+	{
+		const char *key = &out->data[key_offset];
+
+		if (!json_unique_check_key(&state->unique_check.check, key, 0))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON key %s", key)));
+
+		if (skip)
+			PG_RETURN_POINTER(state);
+	}
+
 	appendStringInfoString(state->str, " : ");
 
 	if (PG_ARGISNULL(2))
@@ -943,6 +1171,42 @@ json_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * json_object_agg aggregate function
+ */
+Datum
+json_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+/*
+ * json_object_agg_strict aggregate function
+ */
+Datum
+json_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * json_object_agg_unique aggregate function
+ */
+Datum
+json_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * json_object_agg_unique_strict aggregate function
+ */
+Datum
+json_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return json_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 /*
  * json_object_agg final function.
  */
@@ -960,6 +1224,8 @@ json_object_agg_finalfn(PG_FUNCTION_ARGS)
 	if (state == NULL)
 		PG_RETURN_NULL();
 
+	json_unique_builder_free(&state->unique_check);
+
 	/* Else return state with appropriate object terminator added */
 	PG_RETURN_TEXT_P(catenate_stringinfo_string(state->str, " }"));
 }
@@ -984,25 +1250,14 @@ catenate_stringinfo_string(StringInfo buffer, const char *addon)
 	return result;
 }
 
-/*
- * SQL function json_build_object(variadic "any")
- */
 Datum
-json_build_object(PG_FUNCTION_ARGS)
+json_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
+	JsonUniqueBuilderState unique_check;
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1016,19 +1271,58 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '{');
 
+	if (unique_keys)
+		json_unique_builder_init(&unique_check);
+
 	for (i = 0; i < nargs; i += 2)
 	{
-		appendStringInfoString(result, sep);
-		sep = ", ";
+		StringInfo	out;
+		bool		skip;
+		int			key_offset;
+
+		/* Skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		if (skip)
+		{
+			/* If key uniqueness check is needed we must save skipped keys */
+			if (!unique_keys)
+				continue;
+
+			out = json_unique_builder_get_skipped_keys(&unique_check);
+		}
+		else
+		{
+			appendStringInfoString(result, sep);
+			sep = ", ";
+			out = result;
+		}
 
 		/* process key */
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-					 errmsg("argument %d cannot be null", i + 1),
+					 errmsg("argument %d cannot be null",  i + 1),
 					 errhint("Object keys should be text.")));
 
-		add_json(args[i], false, result, types[i], true);
+		/* save key offset before key appending */
+		key_offset = out->len;
+
+		add_json(args[i], false, out, types[i], true);
+
+		if (unique_keys)
+		{
+			/* check key uniqueness after key appending */
+			const char *key = &out->data[key_offset];
+
+			if (!json_unique_check_key(&unique_check.check, key, 0))
+				ereport(ERROR,
+						(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+						 errmsg("duplicate JSON key %s", key)));
+
+			if (skip)
+				continue;
+		}
 
 		appendStringInfoString(result, " : ");
 
@@ -1038,7 +1332,29 @@ json_build_object(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, '}');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	if (unique_keys)
+		json_unique_builder_free(&unique_check);
+
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_object(variadic "any")
+ */
+Datum
+json_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1050,25 +1366,13 @@ json_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_TEXT_P(cstring_to_text_with_len("{}", 2));
 }
 
-/*
- * SQL function json_build_array(variadic "any")
- */
 Datum
-json_build_array(PG_FUNCTION_ARGS)
+json_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	const char *sep = "";
 	StringInfo	result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* fetch argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, false, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	result = makeStringInfo();
 
@@ -1076,6 +1380,9 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	for (i = 0; i < nargs; i++)
 	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		appendStringInfoString(result, sep);
 		sep = ", ";
 		add_json(args[i], nulls[i], result, types[i], false);
@@ -1083,7 +1390,26 @@ json_build_array(PG_FUNCTION_ARGS)
 
 	appendStringInfoChar(result, ']');
 
-	PG_RETURN_TEXT_P(cstring_to_text_with_len(result->data, result->len));
+	return PointerGetDatum(cstring_to_text_with_len(result->data, result->len));
+}
+
+/*
+ * SQL function json_build_array(variadic "any")
+ */
+Datum
+json_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(json_build_array_worker(nargs, args, nulls, types, false));
 }
 
 /*
@@ -1317,6 +1643,106 @@ escape_json(StringInfo buf, const char *str)
 	appendStringInfoCharMacro(buf, '"');
 }
 
+/* Semantic actions for key uniqueness check */
+static void
+json_unique_object_start(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* push object entry to stack */
+	entry = palloc(sizeof(*entry));
+	entry->object_id = state->id_counter++;
+	entry->parent = state->stack;
+	state->stack = entry;
+}
+
+static void
+json_unique_object_end(void *_state)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	entry = state->stack;
+	state->stack = entry->parent;	/* pop object from stack */
+	pfree(entry);
+}
+
+static void
+json_unique_object_field_start(void *_state, char *field, bool isnull)
+{
+	JsonUniqueParsingState *state = _state;
+	JsonUniqueStackEntry *entry;
+
+	if (!state->unique)
+		return;
+
+	/* find key collision in the current object */
+	if (json_unique_check_key(&state->check, field, state->stack->object_id))
+		return;
+
+	state->unique = false;
+
+	/* pop all objects entries */
+	while ((entry = state->stack))
+	{
+		state->stack = entry->parent;
+		pfree(entry);
+	}
+}
+
+/* Validate JSON text and additionally check key uniqueness */
+bool
+json_validate(text *json, bool check_unique_keys, bool throw_error)
+{
+	JsonLexContext *lex = makeJsonLexContext(json, check_unique_keys);
+	JsonSemAction uniqueSemAction = {0};
+	JsonUniqueParsingState state;
+	JsonParseErrorType result;
+
+	if (check_unique_keys)
+	{
+		state.lex = lex;
+		state.stack = NULL;
+		state.id_counter = 0;
+		state.unique = true;
+		json_unique_check_init(&state.check);
+
+		uniqueSemAction.semstate = &state;
+		uniqueSemAction.object_start = json_unique_object_start;
+		uniqueSemAction.object_field_start = json_unique_object_field_start;
+		uniqueSemAction.object_end = json_unique_object_end;
+	}
+
+	result = pg_parse_json(lex, check_unique_keys ? &uniqueSemAction : &nullSemAction);
+
+	if (result != JSON_SUCCESS)
+	{
+		if (throw_error)
+			json_ereport_error(result, lex);
+
+		return false;	/* invalid json */
+	}
+
+	if (check_unique_keys && !state.unique)
+	{
+		if (throw_error)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+					 errmsg("duplicate JSON object key value")));
+
+		return false;	/* not unique keys */
+	}
+
+	return true;	/* ok */
+}
+
 /*
  * SQL function json_typeof(json) -> text
  *
@@ -1332,21 +1758,13 @@ escape_json(StringInfo buf, const char *str)
 Datum
 json_typeof(PG_FUNCTION_ARGS)
 {
-	text	   *json;
-
-	JsonLexContext *lex;
-	JsonTokenType tok;
+	text	   *json = PG_GETARG_TEXT_PP(0);
 	char	   *type;
-	JsonParseErrorType result;
-
-	json = PG_GETARG_TEXT_PP(0);
-	lex = makeJsonLexContext(json, false);
+	JsonTokenType tok;
 
 	/* Lex exactly one token from the input and check its type. */
-	result = json_lex(lex);
-	if (result != JSON_SUCCESS)
-		json_ereport_error(result, lex);
-	tok = lex->token_type;
+	tok = json_get_first_token(json, true);
+
 	switch (tok)
 	{
 		case JSON_TOKEN_OBJECT_START:
diff --git a/src/backend/utils/adt/jsonb.c b/src/backend/utils/adt/jsonb.c
index f5f40a94bd..2043f2e74a 100644
--- a/src/backend/utils/adt/jsonb.c
+++ b/src/backend/utils/adt/jsonb.c
@@ -14,6 +14,7 @@
 
 #include "access/htup_details.h"
 #include "access/transam.h"
+#include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "funcapi.h"
 #include "libpq/pqformat.h"
@@ -33,25 +34,9 @@ typedef struct JsonbInState
 {
 	JsonbParseState *parseState;
 	JsonbValue *res;
+	bool		unique_keys;
 } JsonbInState;
 
-/* unlike with json categories, we need to treat json and jsonb differently */
-typedef enum					/* type categories for datum_to_jsonb */
-{
-	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
-	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
-	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
-	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
-	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
-	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
-	JSONBTYPE_JSON,				/* JSON */
-	JSONBTYPE_JSONB,			/* JSONB */
-	JSONBTYPE_ARRAY,			/* array */
-	JSONBTYPE_COMPOSITE,		/* composite */
-	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
-	JSONBTYPE_OTHER				/* all else */
-} JsonbTypeCategory;
-
 typedef struct JsonbAggState
 {
 	JsonbInState *res;
@@ -61,7 +46,7 @@ typedef struct JsonbAggState
 	Oid			val_output_func;
 } JsonbAggState;
 
-static inline Datum jsonb_from_cstring(char *json, int len);
+static inline Datum jsonb_from_cstring(char *json, int len, bool unique_keys);
 static size_t checkStringLen(size_t len);
 static void jsonb_in_object_start(void *pstate);
 static void jsonb_in_object_end(void *pstate);
@@ -70,17 +55,11 @@ static void jsonb_in_array_end(void *pstate);
 static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
 static void jsonb_put_escaped_value(StringInfo out, JsonbValue *scalarVal);
 static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void composite_to_jsonb(Datum composite, JsonbInState *result);
 static void array_dim_to_jsonb(JsonbInState *result, int dim, int ndims, int *dims,
 							   Datum *vals, bool *nulls, int *valcount,
 							   JsonbTypeCategory tcategory, Oid outfuncoid);
 static void array_to_jsonb_internal(Datum array, JsonbInState *result);
-static void jsonb_categorize_type(Oid typoid,
-								  JsonbTypeCategory *tcategory,
-								  Oid *outfuncoid);
 static void datum_to_jsonb(Datum val, bool is_null, JsonbInState *result,
 						   JsonbTypeCategory tcategory, Oid outfuncoid,
 						   bool key_scalar);
@@ -98,7 +77,7 @@ jsonb_in(PG_FUNCTION_ARGS)
 {
 	char	   *json = PG_GETARG_CSTRING(0);
 
-	return jsonb_from_cstring(json, strlen(json));
+	return jsonb_from_cstring(json, strlen(json), false);
 }
 
 /*
@@ -122,7 +101,7 @@ jsonb_recv(PG_FUNCTION_ARGS)
 	else
 		elog(ERROR, "unsupported jsonb version number %d", version);
 
-	return jsonb_from_cstring(str, nbytes);
+	return jsonb_from_cstring(str, nbytes, false);
 }
 
 /*
@@ -163,6 +142,14 @@ jsonb_send(PG_FUNCTION_ARGS)
 	PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
 }
 
+Datum
+jsonb_from_text(text *js, bool unique_keys)
+{
+	return jsonb_from_cstring(VARDATA_ANY(js),
+							  VARSIZE_ANY_EXHDR(js),
+							  unique_keys);
+}
+
 /*
  * Get the type name of a jsonb container.
  */
@@ -253,7 +240,7 @@ jsonb_typeof(PG_FUNCTION_ARGS)
  * Uses the json parser (with hooks) to construct a jsonb.
  */
 static inline Datum
-jsonb_from_cstring(char *json, int len)
+jsonb_from_cstring(char *json, int len, bool unique_keys)
 {
 	JsonLexContext *lex;
 	JsonbInState state;
@@ -263,6 +250,8 @@ jsonb_from_cstring(char *json, int len)
 	memset(&sem, 0, sizeof(sem));
 	lex = makeJsonLexContextCstringLen(json, len, GetDatabaseEncoding(), true);
 
+	state.unique_keys = unique_keys;
+
 	sem.semstate = (void *) &state;
 
 	sem.object_start = jsonb_in_object_start;
@@ -297,6 +286,7 @@ jsonb_in_object_start(void *pstate)
 	JsonbInState *_state = (JsonbInState *) pstate;
 
 	_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
+	_state->parseState->unique_keys = _state->unique_keys;
 }
 
 static void
@@ -619,7 +609,7 @@ add_indent(StringInfo out, bool indent, int level)
  * output function OID.  If the returned category is JSONBTYPE_JSONCAST,
  * we return the OID of the relevant cast function instead.
  */
-static void
+void
 jsonb_categorize_type(Oid typoid,
 					  JsonbTypeCategory *tcategory,
 					  Oid *outfuncoid)
@@ -1126,6 +1116,51 @@ add_jsonb(Datum val, bool is_null, JsonbInState *result,
 	datum_to_jsonb(val, is_null, result, tcategory, outfuncoid, key_scalar);
 }
 
+Datum
+to_jsonb_worker(Datum val, JsonbTypeCategory tcategory, Oid outfuncoid)
+{
+	JsonbInState result;
+
+	memset(&result, 0, sizeof(JsonbInState));
+
+	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
+
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+bool
+to_jsonb_is_immutable(Oid typoid)
+{
+	JsonbTypeCategory tcategory;
+	Oid			outfuncoid;
+
+	jsonb_categorize_type(typoid, &tcategory, &outfuncoid);
+
+	switch (tcategory)
+	{
+		case JSONBTYPE_BOOL:
+		case JSONBTYPE_JSON:
+		case JSONBTYPE_JSONB:
+			return true;
+
+		case JSONBTYPE_DATE:
+		case JSONBTYPE_TIMESTAMP:
+		case JSONBTYPE_TIMESTAMPTZ:
+			return false;
+
+		case JSONBTYPE_ARRAY:
+			return false;	/* TODO recurse into elements */
+
+		case JSONBTYPE_COMPOSITE:
+			return false;	/* TODO recurse into fields */
+
+		case JSONBTYPE_NUMERIC:
+		case JSONBTYPE_JSONCAST:
+		default:
+			return func_volatile(outfuncoid) == PROVOLATILE_IMMUTABLE;
+	}
+}
+
 /*
  * SQL function to_jsonb(anyvalue)
  */
@@ -1134,7 +1169,6 @@ to_jsonb(PG_FUNCTION_ARGS)
 {
 	Datum		val = PG_GETARG_DATUM(0);
 	Oid			val_type = get_fn_expr_argtype(fcinfo->flinfo, 0);
-	JsonbInState result;
 	JsonbTypeCategory tcategory;
 	Oid			outfuncoid;
 
@@ -1146,31 +1180,15 @@ to_jsonb(PG_FUNCTION_ARGS)
 	jsonb_categorize_type(val_type,
 						  &tcategory, &outfuncoid);
 
-	memset(&result, 0, sizeof(JsonbInState));
-
-	datum_to_jsonb(val, false, &result, tcategory, outfuncoid, false);
-
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	PG_RETURN_DATUM(to_jsonb_worker(val, tcategory, outfuncoid));
 }
 
-/*
- * SQL function jsonb_build_object(variadic "any")
- */
 Datum
-jsonb_build_object(PG_FUNCTION_ARGS)
+jsonb_build_object_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						  bool absent_on_null, bool unique_keys)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the object */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	if (nargs % 2 != 0)
 		ereport(ERROR,
@@ -1183,15 +1201,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_OBJECT, NULL);
+	result.parseState->unique_keys = unique_keys;
+	result.parseState->skip_nulls = absent_on_null;
 
 	for (i = 0; i < nargs; i += 2)
 	{
 		/* process key */
+		bool		skip;
+
 		if (nulls[i])
 			ereport(ERROR,
 					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 					 errmsg("argument %d: key must not be null", i + 1)));
 
+		/* skip null values if absent_on_null */
+		skip = absent_on_null && nulls[i + 1];
+
+		/* we need to save skipped keys for the key uniqueness check */
+		if (skip && !unique_keys)
+			continue;
+
 		add_jsonb(args[i], false, &result, types[i], true);
 
 		/* process value */
@@ -1200,7 +1229,26 @@ jsonb_build_object(PG_FUNCTION_ARGS)
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_OBJECT, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_object(variadic "any")
+ */
+Datum
+jsonb_build_object(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_object_worker(nargs, args, nulls, types, false, false));
 }
 
 /*
@@ -1219,37 +1267,50 @@ jsonb_build_object_noargs(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
 }
 
-/*
- * SQL function jsonb_build_array(variadic "any")
- */
 Datum
-jsonb_build_array(PG_FUNCTION_ARGS)
+jsonb_build_array_worker(int nargs, Datum *args, bool *nulls, Oid *types,
+						 bool absent_on_null)
 {
-	int			nargs;
 	int			i;
 	JsonbInState result;
-	Datum	   *args;
-	bool	   *nulls;
-	Oid		   *types;
-
-	/* build argument values to build the array */
-	nargs = extract_variadic_args(fcinfo, 0, true, &args, &types, &nulls);
-
-	if (nargs < 0)
-		PG_RETURN_NULL();
 
 	memset(&result, 0, sizeof(JsonbInState));
 
 	result.res = pushJsonbValue(&result.parseState, WJB_BEGIN_ARRAY, NULL);
 
 	for (i = 0; i < nargs; i++)
+	{
+		if (absent_on_null && nulls[i])
+			continue;
+
 		add_jsonb(args[i], nulls[i], &result, types[i], false);
+	}
 
 	result.res = pushJsonbValue(&result.parseState, WJB_END_ARRAY, NULL);
 
-	PG_RETURN_POINTER(JsonbValueToJsonb(result.res));
+	return JsonbPGetDatum(JsonbValueToJsonb(result.res));
+}
+
+/*
+ * SQL function jsonb_build_array(variadic "any")
+ */
+Datum
+jsonb_build_array(PG_FUNCTION_ARGS)
+{
+	Datum	   *args;
+	bool	   *nulls;
+	Oid		   *types;
+	/* build argument values to build the object */
+	int			nargs = extract_variadic_args(fcinfo, 0, true,
+											  &args, &types, &nulls);
+
+	if (nargs < 0)
+		PG_RETURN_NULL();
+
+	PG_RETURN_DATUM(jsonb_build_array_worker(nargs, args, nulls, types, false));
 }
 
+
 /*
  * degenerate case of jsonb_build_array where it gets 0 arguments.
  */
@@ -1490,6 +1551,8 @@ clone_parse_state(JsonbParseState *state)
 	{
 		ocursor->contVal = icursor->contVal;
 		ocursor->size = icursor->size;
+		ocursor->unique_keys = icursor->unique_keys;
+		ocursor->skip_nulls = icursor->skip_nulls;
 		icursor = icursor->next;
 		if (icursor == NULL)
 			break;
@@ -1501,12 +1564,8 @@ clone_parse_state(JsonbParseState *state)
 	return result;
 }
 
-
-/*
- * jsonb_agg aggregate function
- */
-Datum
-jsonb_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_agg_transfn_worker(FunctionCallInfo fcinfo, bool absent_on_null)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1554,6 +1613,9 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 		result = state->res;
 	}
 
+	if (absent_on_null && PG_ARGISNULL(1))
+		PG_RETURN_POINTER(state);
+
 	/* turn the argument into jsonb in the normal function context */
 
 	val = PG_ARGISNULL(1) ? (Datum) 0 : PG_GETARG_DATUM(1);
@@ -1623,6 +1685,24 @@ jsonb_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_agg aggregate function
+ */
+Datum
+jsonb_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, false);
+}
+
+/*
+ * jsonb_agg_strict aggregate function
+ */
+Datum
+jsonb_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_agg_transfn_worker(fcinfo, true);
+}
+
 Datum
 jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -1655,11 +1735,9 @@ jsonb_agg_finalfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(out);
 }
 
-/*
- * jsonb_object_agg aggregate function
- */
-Datum
-jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+static Datum
+jsonb_object_agg_transfn_worker(FunctionCallInfo fcinfo,
+								bool absent_on_null, bool unique_keys)
 {
 	MemoryContext oldcontext,
 				aggcontext;
@@ -1673,6 +1751,7 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 			   *jbval;
 	JsonbValue	v;
 	JsonbIteratorToken type;
+	bool		skip;
 
 	if (!AggCheckCallContext(fcinfo, &aggcontext))
 	{
@@ -1692,6 +1771,9 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 		state->res = result;
 		result->res = pushJsonbValue(&result->parseState,
 									 WJB_BEGIN_OBJECT, NULL);
+		result->parseState->unique_keys = unique_keys;
+		result->parseState->skip_nulls = absent_on_null;
+
 		MemoryContextSwitchTo(oldcontext);
 
 		arg_type = get_fn_expr_argtype(fcinfo->flinfo, 1);
@@ -1727,6 +1809,15 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
 				 errmsg("field name must not be null")));
 
+	/*
+	 * Skip null values if absent_on_null unless key uniqueness check is
+	 * needed (because we must save keys in this case).
+	 */
+	skip = absent_on_null && PG_ARGISNULL(2);
+
+	if (skip && !unique_keys)
+		PG_RETURN_POINTER(state);
+
 	val = PG_GETARG_DATUM(1);
 
 	memset(&elem, 0, sizeof(JsonbInState));
@@ -1782,6 +1873,16 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 				}
 				result->res = pushJsonbValue(&result->parseState,
 											 WJB_KEY, &v);
+
+				if (skip)
+				{
+					v.type = jbvNull;
+					result->res = pushJsonbValue(&result->parseState,
+												 WJB_VALUE, &v);
+					MemoryContextSwitchTo(oldcontext);
+					PG_RETURN_POINTER(state);
+				}
+
 				break;
 			case WJB_END_ARRAY:
 				break;
@@ -1854,6 +1955,43 @@ jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
 	PG_RETURN_POINTER(state);
 }
 
+/*
+ * jsonb_object_agg aggregate function
+ */
+Datum
+jsonb_object_agg_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, false);
+}
+
+
+/*
+ * jsonb_object_agg_strict aggregate function
+ */
+Datum
+jsonb_object_agg_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, false);
+}
+
+/*
+ * jsonb_object_agg_unique aggregate function
+ */
+Datum
+jsonb_object_agg_unique_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, false, true);
+}
+
+/*
+ * jsonb_object_agg_unique_strict aggregate function
+ */
+Datum
+jsonb_object_agg_unique_strict_transfn(PG_FUNCTION_ARGS)
+{
+	return jsonb_object_agg_transfn_worker(fcinfo, true, true);
+}
+
 Datum
 jsonb_object_agg_finalfn(PG_FUNCTION_ARGS)
 {
@@ -2085,3 +2223,65 @@ jsonb_float8(PG_FUNCTION_ARGS)
 
 	PG_RETURN_DATUM(retValue);
 }
+
+/*
+ * Construct an empty array jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyArray(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvArray;
+	jbv.val.array.elems = NULL;
+	jbv.val.array.nElems = 0;
+	jbv.val.array.rawScalar = false;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Construct an empty object jsonb.
+ */
+Jsonb *
+JsonbMakeEmptyObject(void)
+{
+	JsonbValue jbv;
+
+	jbv.type = jbvObject;
+	jbv.val.object.pairs = NULL;
+	jbv.val.object.nPairs = 0;
+
+	return JsonbValueToJsonb(&jbv);
+}
+
+/*
+ * Convert jsonb to a C-string stripping quotes from scalar strings.
+ */
+char *
+JsonbUnquote(Jsonb *jb)
+{
+	if (JB_ROOT_IS_SCALAR(jb))
+	{
+		JsonbValue	v;
+
+		JsonbExtractScalar(&jb->root, &v);
+
+		if (v.type == jbvString)
+			return pnstrdup(v.val.string.val, v.val.string.len);
+		else if (v.type == jbvBool)
+			return pstrdup(v.val.boolean ? "true" : "false");
+		else if (v.type == jbvNumeric)
+			return DatumGetCString(DirectFunctionCall1(numeric_out,
+									   PointerGetDatum(v.val.numeric)));
+		else if (v.type == jbvNull)
+			return pstrdup("null");
+		else
+		{
+			elog(ERROR, "unrecognized jsonb value type %d", v.type);
+			return NULL;
+		}
+	}
+	else
+		return JsonbToCString(NULL, &jb->root, VARSIZE(jb));
+}
diff --git a/src/backend/utils/adt/jsonb_util.c b/src/backend/utils/adt/jsonb_util.c
index 60442758b3..aa151a53d6 100644
--- a/src/backend/utils/adt/jsonb_util.c
+++ b/src/backend/utils/adt/jsonb_util.c
@@ -64,7 +64,8 @@ static int	lengthCompareJsonbStringValue(const void *a, const void *b);
 static int	lengthCompareJsonbString(const char *val1, int len1,
 									 const char *val2, int len2);
 static int	lengthCompareJsonbPair(const void *a, const void *b, void *arg);
-static void uniqueifyJsonbObject(JsonbValue *object);
+static void uniqueifyJsonbObject(JsonbValue *object, bool unique_keys,
+								 bool skip_nulls);
 static JsonbValue *pushJsonbValueScalar(JsonbParseState **pstate,
 										JsonbIteratorToken seq,
 										JsonbValue *scalarVal);
@@ -689,7 +690,9 @@ pushJsonbValueScalar(JsonbParseState **pstate, JsonbIteratorToken seq,
 			appendElement(*pstate, scalarVal);
 			break;
 		case WJB_END_OBJECT:
-			uniqueifyJsonbObject(&(*pstate)->contVal);
+			uniqueifyJsonbObject(&(*pstate)->contVal,
+								 (*pstate)->unique_keys,
+								 (*pstate)->skip_nulls);
 			/* fall through! */
 		case WJB_END_ARRAY:
 			/* Steps here common to WJB_END_OBJECT case */
@@ -732,6 +735,9 @@ pushState(JsonbParseState **pstate)
 	JsonbParseState *ns = palloc(sizeof(JsonbParseState));
 
 	ns->next = *pstate;
+	ns->unique_keys = false;
+	ns->skip_nulls = false;
+
 	return ns;
 }
 
@@ -1936,7 +1942,7 @@ lengthCompareJsonbPair(const void *a, const void *b, void *binequal)
  * Sort and unique-ify pairs in JsonbValue object
  */
 static void
-uniqueifyJsonbObject(JsonbValue *object)
+uniqueifyJsonbObject(JsonbValue *object, bool unique_keys, bool skip_nulls)
 {
 	bool		hasNonUniq = false;
 
@@ -1946,15 +1952,21 @@ uniqueifyJsonbObject(JsonbValue *object)
 		qsort_arg(object->val.object.pairs, object->val.object.nPairs, sizeof(JsonbPair),
 				  lengthCompareJsonbPair, &hasNonUniq);
 
-	if (hasNonUniq)
+	if (hasNonUniq && unique_keys)
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_JSON_OBJECT_KEY_VALUE),
+				 errmsg("duplicate JSON object key value")));
+
+	if (hasNonUniq || skip_nulls)
 	{
 		JsonbPair  *ptr = object->val.object.pairs + 1,
 				   *res = object->val.object.pairs;
 
 		while (ptr - object->val.object.pairs < object->val.object.nPairs)
 		{
-			/* Avoid copying over duplicate */
-			if (lengthCompareJsonbStringValue(ptr, res) != 0)
+			/* Avoid copying over duplicate or null */
+			if (lengthCompareJsonbStringValue(ptr, res) != 0 &&
+				(!skip_nulls || ptr->value.type != jbvNull))
 			{
 				res++;
 				if (ptr != res)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 29664aa6e4..a682d9c973 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -2658,11 +2658,11 @@ populate_array_dim_jsonb(PopulateArrayContext *ctx, /* context */
 
 	check_stack_depth();
 
-	if (jbv->type != jbvBinary || !JsonContainerIsArray(jbc))
+	if (jbv->type != jbvBinary ||
+		!JsonContainerIsArray(jbc) ||
+		JsonContainerIsScalar(jbc))
 		populate_array_report_expected_array(ctx, ndim - 1);
 
-	Assert(!JsonContainerIsScalar(jbc));
-
 	it = JsonbIteratorInit(jbc);
 
 	tok = JsonbIteratorNext(&it, &val, true);
@@ -3134,6 +3134,50 @@ populate_record_field(ColumnIOData *col,
 	}
 }
 
+/* recursively populate specified type from a json/jsonb value */
+Datum
+json_populate_type(Datum json_val, Oid json_type, Oid typid, int32 typmod,
+				   void **cache, MemoryContext mcxt, bool *isnull)
+{
+	JsValue		jsv = { 0 };
+	JsonbValue	jbv;
+
+	jsv.is_json = json_type == JSONOID;
+
+	if (*isnull)
+	{
+		if (jsv.is_json)
+			jsv.val.json.str = NULL;
+		else
+			jsv.val.jsonb = NULL;
+	}
+	else if (jsv.is_json)
+	{
+		text	   *json = DatumGetTextPP(json_val);
+
+		jsv.val.json.str = VARDATA_ANY(json);
+		jsv.val.json.len = VARSIZE_ANY_EXHDR(json);
+		jsv.val.json.type = JSON_TOKEN_INVALID; /* not used in populate_composite() */
+	}
+	else
+	{
+		Jsonb	   *jsonb = DatumGetJsonbP(json_val);
+
+		jsv.val.jsonb = &jbv;
+
+		/* fill binary jsonb value pointing to jb */
+		jbv.type = jbvBinary;
+		jbv.val.binary.data = &jsonb->root;
+		jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+	}
+
+	if (!*cache)
+		*cache = MemoryContextAllocZero(mcxt, sizeof(ColumnIOData));
+
+	return populate_record_field(*cache , typid, typmod, NULL, mcxt,
+								 PointerGetDatum(NULL), &jsv, isnull);
+}
+
 static RecordIOData *
 allocate_record_info(MemoryContext mcxt, int ncolumns)
 {
@@ -5528,3 +5572,23 @@ transform_string_values_scalar(void *state, char *token, JsonTokenType tokentype
 	else
 		appendStringInfoString(_state->strval, token);
 }
+
+JsonTokenType
+json_get_first_token(text *json, bool throw_error)
+{
+	JsonLexContext *lex;
+	JsonParseErrorType result;
+
+	lex = makeJsonLexContext(json, false);
+
+	/* Lex exactly one token from the input and check its type. */
+	result = json_lex(lex);
+
+	if (result == JSON_SUCCESS)
+		return lex->token_type;
+
+	if (throw_error)
+		json_ereport_error(result, lex);
+
+	return JSON_TOKEN_INVALID;	/* invalid json */
+}
diff --git a/src/backend/utils/adt/jsonpath.c b/src/backend/utils/adt/jsonpath.c
index 9be4e305ff..ca1cfe3d36 100644
--- a/src/backend/utils/adt/jsonpath.c
+++ b/src/backend/utils/adt/jsonpath.c
@@ -67,7 +67,9 @@
 #include "lib/stringinfo.h"
 #include "libpq/pqformat.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "utils/builtins.h"
+#include "utils/formatting.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
 
@@ -1073,3 +1075,258 @@ jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from, JsonPathItem *to,
 
 	return true;
 }
+
+/* SQL/JSON datatype status: */
+typedef enum JsonPathDatatypeStatus
+{
+	jpdsNonDateTime,			/* null, bool, numeric, string, array, object */
+	jpdsUnknownDateTime,		/* unknown datetime type */
+	jpdsDateTimeZoned,			/* timetz, timestamptz */
+	jpdsDateTimeNonZoned		/* time, timestamp, date */
+} JsonPathDatatypeStatus;
+
+/* Context for jspIsMutableWalker() */
+typedef struct JsonPathMutableContext
+{
+	List	   *varnames;		/* list of variable names */
+	List	   *varexprs;		/* list of variable expressions */
+	JsonPathDatatypeStatus current;	/* status of @ item */
+	bool		lax;			/* jsonpath is lax or strict */
+	bool		mutable;		/* resulting mutability status */
+} JsonPathMutableContext;
+
+/*
+ * Recursive walker for jspIsMutable()
+ */
+static JsonPathDatatypeStatus
+jspIsMutableWalker(JsonPathItem *jpi, JsonPathMutableContext *cxt)
+{
+	JsonPathItem next;
+	JsonPathDatatypeStatus status = jpdsNonDateTime;
+
+	while (!cxt->mutable)
+	{
+		JsonPathItem arg;
+		JsonPathDatatypeStatus leftStatus;
+		JsonPathDatatypeStatus rightStatus;
+
+		switch (jpi->type)
+		{
+			case jpiRoot:
+				Assert(status == jpdsNonDateTime);
+				break;
+
+			case jpiCurrent:
+				Assert(status == jpdsNonDateTime);
+				status = cxt->current;
+				break;
+
+			case jpiFilter:
+				{
+					JsonPathDatatypeStatus prevStatus = cxt->current;
+
+					cxt->current = status;
+					jspGetArg(jpi, &arg);
+					jspIsMutableWalker(&arg, cxt);
+
+					cxt->current = prevStatus;
+					break;
+				}
+
+			case jpiVariable:
+				{
+					int32		len;
+					const char *name = jspGetString(jpi, &len);
+					ListCell   *lc1;
+					ListCell   *lc2;
+
+					Assert(status == jpdsNonDateTime);
+
+					forboth(lc1, cxt->varnames, lc2, cxt->varexprs)
+					{
+						String	   *varname = lfirst_node(String, lc1);
+						Node	   *varexpr = lfirst(lc2);
+
+						if (strncmp(varname->sval, name, len))
+							continue;
+
+						switch (exprType(varexpr))
+						{
+							case DATEOID:
+							case TIMEOID:
+							case TIMESTAMPOID:
+								status = jpdsDateTimeNonZoned;
+								break;
+
+							case TIMETZOID:
+							case TIMESTAMPTZOID:
+								status = jpdsDateTimeZoned;
+								break;
+
+							default:
+								status = jpdsNonDateTime;
+								break;
+						}
+
+						break;
+					}
+					break;
+				}
+
+			case jpiEqual:
+			case jpiNotEqual:
+			case jpiLess:
+			case jpiGreater:
+			case jpiLessOrEqual:
+			case jpiGreaterOrEqual:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				leftStatus = jspIsMutableWalker(&arg, cxt);
+
+				jspGetRightArg(jpi, &arg);
+				rightStatus = jspIsMutableWalker(&arg, cxt);
+
+				/*
+				 * Comparison of datetime type with different timezone status
+				 * is mutable.
+				 */
+				if (leftStatus != jpdsNonDateTime &&
+					rightStatus != jpdsNonDateTime &&
+					(leftStatus == jpdsUnknownDateTime ||
+					 rightStatus == jpdsUnknownDateTime ||
+					 leftStatus != rightStatus))
+					cxt->mutable = true;
+				break;
+
+			case jpiNot:
+			case jpiIsUnknown:
+			case jpiExists:
+			case jpiPlus:
+			case jpiMinus:
+				Assert(status == jpdsNonDateTime);
+				jspGetArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiAnd:
+			case jpiOr:
+			case jpiAdd:
+			case jpiSub:
+			case jpiMul:
+			case jpiDiv:
+			case jpiMod:
+			case jpiStartsWith:
+				Assert(status == jpdsNonDateTime);
+				jspGetLeftArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				jspGetRightArg(jpi, &arg);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			case jpiIndexArray:
+				for (int i = 0; i < jpi->content.array.nelems; i++)
+				{
+					JsonPathItem from;
+					JsonPathItem to;
+
+					if (jspGetArraySubscript(jpi, &from, &to, i))
+						jspIsMutableWalker(&to, cxt);
+
+					jspIsMutableWalker(&from, cxt);
+				}
+				/* FALLTHROUGH */
+
+			case jpiAnyArray:
+				if (!cxt->lax)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiAny:
+				if (jpi->content.anybounds.first > 0)
+					status = jpdsNonDateTime;
+				break;
+
+			case jpiDatetime:
+				if (jpi->content.arg)
+				{
+					char	   *template;
+					int			flags;
+
+					jspGetArg(jpi, &arg);
+					if (arg.type != jpiString)
+					{
+						status = jpdsNonDateTime;
+						break;	/* there will be runtime error */
+					}
+
+					template = jspGetString(&arg, NULL);
+					flags = datetime_format_flags(template, NULL);
+					if (flags & DCH_ZONED)
+						status = jpdsDateTimeZoned;
+					else
+						status = jpdsDateTimeNonZoned;
+				}
+				else
+				{
+					status = jpdsUnknownDateTime;
+				}
+				break;
+
+			case jpiLikeRegex:
+				Assert(status == jpdsNonDateTime);
+				jspInitByBuffer(&arg, jpi->base, jpi->content.like_regex.expr);
+				jspIsMutableWalker(&arg, cxt);
+				break;
+
+			/* literals */
+			case jpiNull:
+			case jpiString:
+			case jpiNumeric:
+			case jpiBool:
+			/* accessors */
+			case jpiKey:
+			case jpiAnyKey:
+			/* special items */
+			case jpiSubscript:
+			case jpiLast:
+			/* item methods */
+			case jpiType:
+			case jpiSize:
+			case jpiAbs:
+			case jpiFloor:
+			case jpiCeiling:
+			case jpiDouble:
+			case jpiKeyValue:
+				status = jpdsNonDateTime;
+				break;
+		}
+
+		if (!jspGetNext(jpi, &next))
+			break;
+
+		jpi = &next;
+	}
+
+	return status;
+}
+
+/*
+ * Check whether jsonpath expression is immutable or not.
+ */
+bool
+jspIsMutable(JsonPath *path, List *varnames, List *varexprs)
+{
+	JsonPathMutableContext cxt;
+	JsonPathItem jpi;
+
+	cxt.varnames = varnames;
+	cxt.varexprs = varexprs;
+	cxt.current = jpdsNonDateTime;
+	cxt.lax = (path->header & JSONPATH_LAX) != 0;
+	cxt.mutable = false;
+
+	jspInit(&jpi, path);
+	jspIsMutableWalker(&jpi, &cxt);
+
+	return cxt.mutable;
+}
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index eff3734b6a..7811fa31e0 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -86,12 +86,16 @@ typedef struct JsonBaseObjectInfo
 	int			id;
 } JsonBaseObjectInfo;
 
+typedef int (*JsonPathVarCallback) (void *vars, char *varName, int varNameLen,
+									JsonbValue *val, JsonbValue *baseObject);
+
 /*
  * Context of jsonpath execution.
  */
 typedef struct JsonPathExecContext
 {
-	Jsonb	   *vars;			/* variables to substitute into jsonpath */
+	void	   *vars;			/* variables to substitute into jsonpath */
+	JsonPathVarCallback getVar;
 	JsonbValue *root;			/* for $ evaluation */
 	JsonbValue *current;		/* for @ evaluation */
 	JsonBaseObjectInfo baseObject;	/* "base object" for .keyvalue()
@@ -173,7 +177,8 @@ typedef JsonPathBool (*JsonPathPredicateCallback) (JsonPathItem *jsp,
 												   void *param);
 typedef Numeric (*BinaryArithmFunc) (Numeric num1, Numeric num2, bool *error);
 
-static JsonPathExecResult executeJsonPath(JsonPath *path, Jsonb *vars,
+static JsonPathExecResult executeJsonPath(JsonPath *path, void *vars,
+										  JsonPathVarCallback getVar,
 										  Jsonb *json, bool throwErrors,
 										  JsonValueList *result, bool useTz);
 static JsonPathExecResult executeItem(JsonPathExecContext *cxt,
@@ -225,7 +230,10 @@ static JsonPathExecResult appendBoolResult(JsonPathExecContext *cxt,
 static void getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 							JsonbValue *value);
 static void getJsonPathVariable(JsonPathExecContext *cxt,
-								JsonPathItem *variable, Jsonb *vars, JsonbValue *value);
+								JsonPathItem *variable, JsonbValue *value);
+static int getJsonPathVariableFromJsonb(void *varsJsonb, char *varName,
+										int varNameLen, JsonbValue *val,
+										JsonbValue *baseObject);
 static int	JsonbArraySize(JsonbValue *jb);
 static JsonPathBool executeComparison(JsonPathItem *cmp, JsonbValue *lv,
 									  JsonbValue *rv, void *p);
@@ -283,7 +291,8 @@ jsonb_path_exists_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	res = executeJsonPath(jp, vars, jb, !silent, NULL, tz);
+	res = executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						  jb, !silent, NULL, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -338,7 +347,8 @@ jsonb_path_match_internal(FunctionCallInfo fcinfo, bool tz)
 		silent = PG_GETARG_BOOL(3);
 	}
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_FREE_IF_COPY(jb, 0);
 	PG_FREE_IF_COPY(jp, 1);
@@ -416,7 +426,8 @@ jsonb_path_query_internal(FunctionCallInfo fcinfo, bool tz)
 		vars = PG_GETARG_JSONB_P_COPY(2);
 		silent = PG_GETARG_BOOL(3);
 
-		(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+		(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+							   jb, !silent, &found, tz);
 
 		funcctx->user_fctx = JsonValueListGetList(&found);
 
@@ -463,7 +474,8 @@ jsonb_path_query_array_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	PG_RETURN_JSONB_P(JsonbValueToJsonb(wrapItemsInArray(&found)));
 }
@@ -494,7 +506,8 @@ jsonb_path_query_first_internal(FunctionCallInfo fcinfo, bool tz)
 	Jsonb	   *vars = PG_GETARG_JSONB_P(2);
 	bool		silent = PG_GETARG_BOOL(3);
 
-	(void) executeJsonPath(jp, vars, jb, !silent, &found, tz);
+	(void) executeJsonPath(jp, vars, getJsonPathVariableFromJsonb,
+						   jb, !silent, &found, tz);
 
 	if (JsonValueListLength(&found) >= 1)
 		PG_RETURN_JSONB_P(JsonbValueToJsonb(JsonValueListHead(&found)));
@@ -536,8 +549,9 @@ jsonb_path_query_first_tz(PG_FUNCTION_ARGS)
  * In other case it tries to find all the satisfied result items.
  */
 static JsonPathExecResult
-executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
-				JsonValueList *result, bool useTz)
+executeJsonPath(JsonPath *path, void *vars, JsonPathVarCallback getVar,
+				Jsonb *json, bool throwErrors, JsonValueList *result,
+				bool useTz)
 {
 	JsonPathExecContext cxt;
 	JsonPathExecResult res;
@@ -549,22 +563,16 @@ executeJsonPath(JsonPath *path, Jsonb *vars, Jsonb *json, bool throwErrors,
 	if (!JsonbExtractScalar(&json->root, &jbv))
 		JsonbInitBinary(&jbv, json);
 
-	if (vars && !JsonContainerIsObject(&vars->root))
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
-				 errmsg("\"vars\" argument is not an object"),
-				 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
-	}
-
 	cxt.vars = vars;
+	cxt.getVar = getVar;
 	cxt.laxMode = (path->header & JSONPATH_LAX) != 0;
 	cxt.ignoreStructuralErrors = cxt.laxMode;
 	cxt.root = &jbv;
 	cxt.current = &jbv;
 	cxt.baseObject.jbc = NULL;
 	cxt.baseObject.id = 0;
-	cxt.lastGeneratedObjectId = vars ? 2 : 1;
+	/* 1 + number of base objects in vars */
+	cxt.lastGeneratedObjectId = 1 + getVar(vars, NULL, 0, NULL, NULL);
 	cxt.innermostArraySize = -1;
 	cxt.throwErrors = throwErrors;
 	cxt.useTz = useTz;
@@ -2093,7 +2101,7 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
 												 &value->val.string.len);
 			break;
 		case jpiVariable:
-			getJsonPathVariable(cxt, item, cxt->vars, value);
+			getJsonPathVariable(cxt, item, value);
 			return;
 		default:
 			elog(ERROR, "unexpected jsonpath item type");
@@ -2105,42 +2113,63 @@ getJsonPathItem(JsonPathExecContext *cxt, JsonPathItem *item,
  */
 static void
 getJsonPathVariable(JsonPathExecContext *cxt, JsonPathItem *variable,
-					Jsonb *vars, JsonbValue *value)
+					JsonbValue *value)
 {
 	char	   *varName;
 	int			varNameLength;
+	JsonbValue	baseObject;
+	int			baseObjectId;
+
+	Assert(variable->type == jpiVariable);
+	varName = jspGetString(variable, &varNameLength);
+
+	if (!cxt->vars ||
+		(baseObjectId = cxt->getVar(cxt->vars, varName, varNameLength, value,
+									&baseObject)) < 0)
+		ereport(ERROR,
+				(errcode(ERRCODE_UNDEFINED_OBJECT),
+				 errmsg("could not find jsonpath variable \"%s\"",
+						pnstrdup(varName, varNameLength))));
+
+	if (baseObjectId > 0)
+		setBaseObject(cxt, &baseObject, baseObjectId);
+}
+
+static int
+getJsonPathVariableFromJsonb(void *varsJsonb, char *varName, int varNameLength,
+							 JsonbValue *value, JsonbValue *baseObject)
+{
+	Jsonb	   *vars = varsJsonb;
 	JsonbValue	tmp;
 	JsonbValue *v;
 
-	if (!vars)
+	if (!varName)
 	{
-		value->type = jbvNull;
-		return;
+		if (vars && !JsonContainerIsObject(&vars->root))
+		{
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("\"vars\" argument is not an object"),
+					 errdetail("Jsonpath parameters should be encoded as key-value pairs of \"vars\" object.")));
+		}
+
+		return vars ? 1 : 0;	/* count of base objects */
 	}
 
-	Assert(variable->type == jpiVariable);
-	varName = jspGetString(variable, &varNameLength);
 	tmp.type = jbvString;
 	tmp.val.string.val = varName;
 	tmp.val.string.len = varNameLength;
 
 	v = findJsonbValueFromContainer(&vars->root, JB_FOBJECT, &tmp);
 
-	if (v)
-	{
-		*value = *v;
-		pfree(v);
-	}
-	else
-	{
-		ereport(ERROR,
-				(errcode(ERRCODE_UNDEFINED_OBJECT),
-				 errmsg("could not find jsonpath variable \"%s\"",
-						pnstrdup(varName, varNameLength))));
-	}
+	if (!v)
+		return -1;
 
-	JsonbInitBinary(&tmp, vars);
-	setBaseObject(cxt, &tmp, 1);
+	*value = *v;
+	pfree(v);
+
+	JsonbInitBinary(baseObject, vars);
+	return 1;
 }
 
 /**************** Support functions for JsonPath execution *****************/
@@ -2797,3 +2826,244 @@ compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 
 	return DatumGetInt32(DirectFunctionCall2(cmpfunc, val1, val2));
 }
+
+/********************Interface to pgsql's executor***************************/
+
+bool
+JsonPathExists(Datum jb, JsonPath *jp, List *vars, bool *error)
+{
+	JsonPathExecResult res = executeJsonPath(jp, vars, EvalJsonPathVar,
+											 DatumGetJsonbP(jb), !error, NULL,
+											 true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+		*error = true;
+
+	return res == jperOk;
+}
+
+Datum
+JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper, bool *empty,
+			  bool *error, List *vars)
+{
+	JsonbValue *first;
+	bool		wrap;
+	JsonValueList found = {0};
+	JsonPathExecResult res PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	res = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						  &found, true);
+
+	Assert(error || !jperIsError(res));
+
+	if (error && jperIsError(res))
+	{
+		*error = true;
+		*empty = false;
+		return (Datum) 0;
+	}
+
+	count = JsonValueListLength(&found);
+
+	first = count ? JsonValueListHead(&found) : NULL;
+
+	if (!first)
+		wrap = false;
+	else if (wrapper == JSW_NONE)
+		wrap = false;
+	else if (wrapper == JSW_UNCONDITIONAL)
+		wrap = true;
+	else if (wrapper == JSW_CONDITIONAL)
+		wrap = count > 1 ||
+			IsAJsonbScalar(first) ||
+			(first->type == jbvBinary &&
+			 JsonContainerIsScalar(first->val.binary.data));
+	else
+	{
+		elog(ERROR, "unrecognized json wrapper %d", wrapper);
+		wrap = false;
+	}
+
+	if (wrap)
+		return JsonbPGetDatum(JsonbValueToJsonb(wrapItemsInArray(&found)));
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return (Datum) 0;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_QUERY should return "
+						"singleton item without wrapper"),
+				 errhint("use WITH WRAPPER clause to wrap SQL/JSON item "
+						 "sequence into array")));
+	}
+
+	if (first)
+		return JsonbPGetDatum(JsonbValueToJsonb(first));
+
+	*empty = true;
+	return PointerGetDatum(NULL);
+}
+
+JsonbValue *
+JsonPathValue(Datum jb, JsonPath *jp, bool *empty, bool *error, List *vars)
+{
+	JsonbValue   *res;
+	JsonValueList found = { 0 };
+	JsonPathExecResult jper PG_USED_FOR_ASSERTS_ONLY;
+	int			count;
+
+	jper = executeJsonPath(jp, vars, EvalJsonPathVar, DatumGetJsonbP(jb), !error,
+						   &found, true);
+
+	Assert(error || !jperIsError(jper));
+
+	if (error && jperIsError(jper))
+	{
+		*error = true;
+		*empty = false;
+		return NULL;
+	}
+
+	count = JsonValueListLength(&found);
+
+	*empty = !count;
+
+	if (*empty)
+		return NULL;
+
+	if (count > 1)
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_MORE_THAN_ONE_SQL_JSON_ITEM),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	res = JsonValueListHead(&found);
+
+	if (res->type == jbvBinary &&
+		JsonContainerIsScalar(res->val.binary.data))
+		JsonbExtractScalar(res->val.binary.data, res);
+
+	if (!IsAJsonbScalar(res))
+	{
+		if (error)
+		{
+			*error = true;
+			return NULL;
+		}
+
+		ereport(ERROR,
+				(errcode(ERRCODE_SQL_JSON_SCALAR_REQUIRED),
+				 errmsg("JSON path expression in JSON_VALUE should return "
+						"singleton scalar item")));
+	}
+
+	if (res->type == jbvNull)
+		return NULL;
+
+	return res;
+}
+
+static void
+JsonbValueInitNumericDatum(JsonbValue *jbv, Datum num)
+{
+	jbv->type = jbvNumeric;
+	jbv->val.numeric = DatumGetNumeric(num);
+}
+
+void
+JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
+{
+	switch (typid)
+	{
+		case BOOLOID:
+			res->type = jbvBool;
+			res->val.boolean = DatumGetBool(val);
+			break;
+		case NUMERICOID:
+			JsonbValueInitNumericDatum(res, val);
+			break;
+		case INT2OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int2_numeric, val));
+			break;
+		case INT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int4_numeric, val));
+			break;
+		case INT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(int8_numeric, val));
+			break;
+		case FLOAT4OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float4_numeric, val));
+			break;
+		case FLOAT8OID:
+			JsonbValueInitNumericDatum(res, DirectFunctionCall1(float8_numeric, val));
+			break;
+		case TEXTOID:
+		case VARCHAROID:
+			res->type = jbvString;
+			res->val.string.val = VARDATA_ANY(val);
+			res->val.string.len = VARSIZE_ANY_EXHDR(val);
+			break;
+		case DATEOID:
+		case TIMEOID:
+		case TIMETZOID:
+		case TIMESTAMPOID:
+		case TIMESTAMPTZOID:
+			res->type = jbvDatetime;
+			res->val.datetime.value = val;
+			res->val.datetime.typid = typid;
+			res->val.datetime.typmod = typmod;
+			res->val.datetime.tz = 0;
+			break;
+		case JSONBOID:
+			{
+				JsonbValue *jbv = res;
+				Jsonb	   *jb = DatumGetJsonbP(val);
+
+				if (JsonContainerIsScalar(&jb->root))
+				{
+					bool		res PG_USED_FOR_ASSERTS_ONLY;
+
+					res = JsonbExtractScalar(&jb->root, jbv);
+					Assert(res);
+				}
+				else
+					JsonbInitBinary(jbv, jb);
+				break;
+			}
+		case JSONOID:
+			{
+				text	   *txt = DatumGetTextP(val);
+				char	   *str = text_to_cstring(txt);
+				Jsonb	   *jb =
+					DatumGetJsonbP(DirectFunctionCall1(jsonb_in,
+													   CStringGetDatum(str)));
+
+				pfree(str);
+
+				JsonItemFromDatum(JsonbPGetDatum(jb), JSONBOID, -1, res);
+				break;
+			}
+		default:
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("only bool, numeric and text types could be "
+							"casted to supported jsonpath types.")));
+	}
+}
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 7f4f3f7369..e9b7970acc 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -457,6 +457,12 @@ static void get_coercion_expr(Node *arg, deparse_context *context,
 							  Node *parentNode);
 static void get_const_expr(Const *constval, deparse_context *context,
 						   int showtype);
+static void get_json_constructor(JsonConstructorExpr *ctor,
+								 deparse_context *context, bool showimplicit);
+static void get_json_agg_constructor(JsonConstructorExpr *ctor,
+									 deparse_context *context,
+									 const char *funcname,
+									 bool is_json_objectagg);
 static void get_const_collation(Const *constval, deparse_context *context);
 static void simple_quote_literal(StringInfo buf, const char *val);
 static void get_sublink_expr(SubLink *sublink, deparse_context *context);
@@ -490,6 +496,8 @@ static char *generate_qualified_type_name(Oid typid);
 static text *string_to_text(char *str);
 static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
+static void get_json_path_spec(Node *path_spec, deparse_context *context,
+							   bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -6245,7 +6253,8 @@ get_rule_sortgroupclause(Index ref, List *tlist, bool force_colno,
 		bool		need_paren = (PRETTY_PAREN(context)
 								  || IsA(expr, FuncExpr)
 								  || IsA(expr, Aggref)
-								  || IsA(expr, WindowFunc));
+								  || IsA(expr, WindowFunc)
+								  || IsA(expr, JsonConstructorExpr));
 
 		if (need_paren)
 			appendStringInfoChar(context->buf, '(');
@@ -8093,6 +8102,8 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_GroupingFunc:
 		case T_WindowFunc:
 		case T_FuncExpr:
+		case T_JsonConstructorExpr:
+		case T_JsonExpr:
 			/* function-like: name(..) or name[..] */
 			return true;
 
@@ -8186,6 +8197,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 		case T_NullTest:
 		case T_BooleanTest:
 		case T_DistinctExpr:
+		case T_JsonIsPredicate:
 			switch (nodeTag(parentNode))
 			{
 				case T_FuncExpr:
@@ -8210,6 +8222,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 				case T_GroupingFunc:	/* own parentheses */
 				case T_WindowFunc:	/* own parentheses */
 				case T_CaseExpr:	/* other separators */
+				case T_JsonExpr: /* own parentheses */
 					return true;
 				default:
 					return false;
@@ -8266,6 +8279,11 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags)
 					return false;
 			}
 
+		case T_JsonValueExpr:
+			/* maybe simple, check args */
+			return isSimpleNode((Node *) ((JsonValueExpr *) node)->raw_expr,
+								node, prettyFlags);
+
 		default:
 			break;
 	}
@@ -8372,6 +8390,121 @@ get_rule_expr_paren(Node *node, deparse_context *context,
 }
 
 
+/*
+ * get_json_path_spec		- Parse back a JSON path specification
+ */
+static void
+get_json_path_spec(Node *path_spec, deparse_context *context, bool showimplicit)
+{
+	if (IsA(path_spec, Const))
+		get_const_expr((Const *) path_spec, context, -1);
+	else
+		get_rule_expr(path_spec, context, showimplicit);
+}
+
+/*
+ * get_json_format			- Parse back a JsonFormat node
+ */
+static void
+get_json_format(JsonFormat *format, StringInfo buf)
+{
+	if (format->format_type == JS_FORMAT_DEFAULT)
+		return;
+
+	appendStringInfoString(buf,
+						   format->format_type == JS_FORMAT_JSONB ?
+						   " FORMAT JSONB" : " FORMAT JSON");
+
+	if (format->encoding != JS_ENC_DEFAULT)
+	{
+		const char *encoding =
+			format->encoding == JS_ENC_UTF16 ? "UTF16" :
+			format->encoding == JS_ENC_UTF32 ? "UTF32" : "UTF8";
+
+		appendStringInfo(buf, " ENCODING %s", encoding);
+	}
+}
+
+/*
+ * get_json_returning		- Parse back a JsonReturning structure
+ */
+static void
+get_json_returning(JsonReturning *returning, StringInfo buf,
+				   bool json_format_by_default)
+{
+	if (!OidIsValid(returning->typid))
+		return;
+
+	appendStringInfo(buf, " RETURNING %s",
+					 format_type_with_typemod(returning->typid,
+											  returning->typmod));
+
+	if (!json_format_by_default ||
+		returning->format->format_type !=
+			(returning->typid == JSONBOID ? JS_FORMAT_JSONB : JS_FORMAT_JSON))
+		get_json_format(returning->format, buf);
+}
+
+static void
+get_json_behavior(JsonBehavior *behavior, deparse_context *context,
+				  const char *on)
+{
+	/*
+	 * The order of array elements must correspond to the order of
+	 * JsonBehaviorType members.
+	 */
+	const char *behavior_names[] =
+	{
+		" NULL",
+		" ERROR",
+		" EMPTY",
+		" TRUE",
+		" FALSE",
+		" UNKNOWN",
+		" EMPTY ARRAY",
+		" EMPTY OBJECT",
+		" DEFAULT "
+	};
+
+	if ((int) behavior->btype < 0 || behavior->btype >= lengthof(behavior_names))
+		elog(ERROR, "invalid json behavior type: %d", behavior->btype);
+
+	appendStringInfoString(context->buf, behavior_names[behavior->btype]);
+
+	if (behavior->btype == JSON_BEHAVIOR_DEFAULT)
+		get_rule_expr(behavior->default_expr, context, false);
+
+	appendStringInfo(context->buf, " ON %s", on);
+}
+
+/*
+ * get_json_expr_options
+ *
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ */
+static void
+get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
+					  JsonBehaviorType default_behavior)
+{
+	if (jsexpr->op == IS_JSON_QUERY)
+	{
+		if (jsexpr->wrapper == JSW_CONDITIONAL)
+			appendStringInfo(context->buf, " WITH CONDITIONAL WRAPPER");
+		else if (jsexpr->wrapper == JSW_UNCONDITIONAL)
+			appendStringInfo(context->buf, " WITH UNCONDITIONAL WRAPPER");
+
+		if (jsexpr->omit_quotes)
+			appendStringInfo(context->buf, " OMIT QUOTES");
+	}
+
+	if (jsexpr->op != IS_JSON_EXISTS &&
+		jsexpr->on_empty->btype != default_behavior)
+		get_json_behavior(jsexpr->on_empty, context, "EMPTY");
+
+	if (jsexpr->on_error->btype != default_behavior)
+		get_json_behavior(jsexpr->on_error, context, "ERROR");
+}
+
 /* ----------
  * get_rule_expr			- Parse back an expression
  *
@@ -9531,6 +9664,110 @@ get_rule_expr(Node *node, deparse_context *context,
 			}
 			break;
 
+
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *jve = (JsonValueExpr *) node;
+
+				get_rule_expr((Node *) jve->raw_expr, context, false);
+				get_json_format(jve->format, context->buf);
+			}
+			break;
+
+		case T_JsonConstructorExpr:
+			get_json_constructor((JsonConstructorExpr *) node, context, false);
+			break;
+
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, '(');
+
+				get_rule_expr_paren(pred->expr, context, true, node);
+
+				appendStringInfoString(context->buf, " IS JSON");
+
+				switch (pred->value_type)
+				{
+					case JS_TYPE_SCALAR:
+						appendStringInfoString(context->buf, " SCALAR");
+						break;
+					case JS_TYPE_ARRAY:
+						appendStringInfoString(context->buf, " ARRAY");
+						break;
+					case JS_TYPE_OBJECT:
+						appendStringInfoString(context->buf, " OBJECT");
+						break;
+					default:
+						break;
+				}
+
+				if (pred->unique_keys)
+					appendStringInfoString(context->buf, " WITH UNIQUE KEYS");
+
+				if (!PRETTY_PAREN(context))
+					appendStringInfoChar(context->buf, ')');
+			}
+			break;
+
+		case T_JsonExpr:
+			{
+				JsonExpr   *jexpr = (JsonExpr *) node;
+
+				switch (jexpr->op)
+				{
+					case IS_JSON_QUERY:
+						appendStringInfoString(buf, "JSON_QUERY(");
+						break;
+					case IS_JSON_VALUE:
+						appendStringInfoString(buf, "JSON_VALUE(");
+						break;
+					case IS_JSON_EXISTS:
+						appendStringInfoString(buf, "JSON_EXISTS(");
+						break;
+				}
+
+				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+				appendStringInfoString(buf, ", ");
+
+				get_json_path_spec(jexpr->path_spec, context, showimplicit);
+
+				if (jexpr->passing_values)
+				{
+					ListCell   *lc1, *lc2;
+					bool		needcomma = false;
+
+					appendStringInfoString(buf, " PASSING ");
+
+					forboth(lc1, jexpr->passing_names,
+							lc2, jexpr->passing_values)
+					{
+						if (needcomma)
+							appendStringInfoString(buf, ", ");
+						needcomma = true;
+
+						get_rule_expr((Node *) lfirst(lc2), context, showimplicit);
+						appendStringInfo(buf, " AS %s",
+										 ((String *) lfirst_node(String, lc1))->sval);
+					}
+				}
+
+				if (jexpr->op != IS_JSON_EXISTS ||
+					jexpr->returning->typid != BOOLOID)
+					get_json_returning(jexpr->returning, context->buf,
+									   jexpr->op == IS_JSON_QUERY);
+
+				get_json_expr_options(jexpr, context,
+									  jexpr->op == IS_JSON_EXISTS ?
+									  JSON_BEHAVIOR_FALSE : JSON_BEHAVIOR_NULL);
+
+				appendStringInfoString(buf, ")");
+			}
+			break;
+
 		case T_List:
 			{
 				char	   *sep;
@@ -9654,6 +9891,7 @@ looks_like_function(Node *node)
 		case T_MinMaxExpr:
 		case T_SQLValueFunction:
 		case T_XmlExpr:
+		case T_JsonExpr:
 			/* these are all accepted by func_expr_common_subexpr */
 			return true;
 		default:
@@ -9799,17 +10037,101 @@ get_func_expr(FuncExpr *expr, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+static void
+get_json_constructor_options(JsonConstructorExpr *ctor, StringInfo buf)
+{
+	if (ctor->absent_on_null)
+	{
+		if (ctor->type == JSCTOR_JSON_OBJECT ||
+			ctor->type == JSCTOR_JSON_OBJECTAGG)
+			appendStringInfoString(buf, " ABSENT ON NULL");
+	}
+	else
+	{
+		if (ctor->type == JSCTOR_JSON_ARRAY ||
+			ctor->type == JSCTOR_JSON_ARRAYAGG)
+			appendStringInfoString(buf, " NULL ON NULL");
+	}
+
+	if (ctor->unique)
+		appendStringInfoString(buf, " WITH UNIQUE KEYS");
+
+	if (!((ctor->type == JSCTOR_JSON_PARSE ||
+		   ctor->type == JSCTOR_JSON_SCALAR) &&
+		  ctor->returning->typid == JSONOID))
+		get_json_returning(ctor->returning, buf, true);
+}
+
+static void
+get_json_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+					 bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	const char *funcname;
+	int			nargs;
+	ListCell   *lc;
+
+	switch (ctor->type)
+	{
+		case JSCTOR_JSON_PARSE:
+			funcname = "JSON";
+			break;
+		case JSCTOR_JSON_SCALAR:
+			funcname = "JSON_SCALAR";
+			break;
+		case JSCTOR_JSON_SERIALIZE:
+			funcname = "JSON_SERIALIZE";
+			break;
+		case JSCTOR_JSON_OBJECT:
+			funcname = "JSON_OBJECT";
+			break;
+		case JSCTOR_JSON_ARRAY:
+			funcname = "JSON_ARRAY";
+			break;
+		case JSCTOR_JSON_OBJECTAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_OBJECTAGG", true);
+		case JSCTOR_JSON_ARRAYAGG:
+			return get_json_agg_constructor(ctor, context, "JSON_ARRAYAGG", false);
+		default:
+			elog(ERROR, "invalid JsonConstructorExprType %d", ctor->type);
+	}
+
+	appendStringInfo(buf, "%s(", funcname);
+
+	nargs = 0;
+	foreach(lc, ctor->args)
+	{
+		if (nargs > 0)
+		{
+			const char *sep = ctor->type == JSCTOR_JSON_OBJECT &&
+				(nargs % 2) != 0 ? " : " : ", ";
+
+			appendStringInfoString(buf, sep);
+		}
+
+		get_rule_expr((Node *) lfirst(lc), context, true);
+
+		nargs++;
+	}
+
+	get_json_constructor_options(ctor, buf);
+
+	appendStringInfo(buf, ")");
+}
+
+
 /*
- * get_agg_expr			- Parse back an Aggref node
+ * get_agg_expr_helper			- Parse back an Aggref node
  */
 static void
-get_agg_expr(Aggref *aggref, deparse_context *context,
-			 Aggref *original_aggref)
+get_agg_expr_helper(Aggref *aggref, deparse_context *context,
+					Aggref *original_aggref, const char *funcname,
+					const char *options, bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
 	int			nargs;
-	bool		use_variadic;
+	bool		use_variadic = false;
 
 	/*
 	 * For a combining aggregate, we look up and deparse the corresponding
@@ -9839,13 +10161,14 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	/* Extract the argument types as seen by the parser */
 	nargs = get_aggregate_argtypes(aggref, argtypes);
 
+	if (!funcname)
+		funcname = generate_function_name(aggref->aggfnoid, nargs, NIL,
+										  argtypes, aggref->aggvariadic,
+										  &use_variadic,
+										  context->special_exprkind);
+
 	/* Print the aggregate name, schema-qualified if needed */
-	appendStringInfo(buf, "%s(%s",
-					 generate_function_name(aggref->aggfnoid, nargs,
-											NIL, argtypes,
-											aggref->aggvariadic,
-											&use_variadic,
-											context->special_exprkind),
+	appendStringInfo(buf, "%s(%s", funcname,
 					 (aggref->aggdistinct != NIL) ? "DISTINCT " : "");
 
 	if (AGGKIND_IS_ORDERED_SET(aggref->aggkind))
@@ -9881,7 +10204,17 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 				if (tle->resjunk)
 					continue;
 				if (i++ > 0)
-					appendStringInfoString(buf, ", ");
+				{
+					if (is_json_objectagg)
+					{
+						if (i > 2)
+							break; /* skip ABSENT ON NULL and WITH UNIQUE args */
+
+						appendStringInfoString(buf, " : ");
+					}
+					else
+						appendStringInfoString(buf, ", ");
+				}
 				if (use_variadic && i == nargs)
 					appendStringInfoString(buf, "VARIADIC ");
 				get_rule_expr(arg, context, true);
@@ -9895,6 +10228,9 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 		}
 	}
 
+	if (options)
+		appendStringInfoString(buf, options);
+
 	if (aggref->aggfilter != NULL)
 	{
 		appendStringInfoString(buf, ") FILTER (WHERE ");
@@ -9904,6 +10240,16 @@ get_agg_expr(Aggref *aggref, deparse_context *context,
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_agg_expr			- Parse back an Aggref node
+ */
+static void
+get_agg_expr(Aggref *aggref, deparse_context *context, Aggref *original_aggref)
+{
+	return get_agg_expr_helper(aggref, context, original_aggref, NULL, NULL,
+							   false);
+}
+
 /*
  * This is a helper function for get_agg_expr().  It's used when we deparse
  * a combining Aggref; resolve_special_varno locates the corresponding partial
@@ -9923,10 +10269,12 @@ get_agg_combine_expr(Node *node, deparse_context *context, void *callback_arg)
 }
 
 /*
- * get_windowfunc_expr	- Parse back a WindowFunc node
+ * get_windowfunc_expr_helper	- Parse back a WindowFunc node
  */
 static void
-get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+get_windowfunc_expr_helper(WindowFunc *wfunc, deparse_context *context,
+						   const char *funcname, const char *options,
+						   bool is_json_objectagg)
 {
 	StringInfo	buf = context->buf;
 	Oid			argtypes[FUNC_MAX_ARGS];
@@ -9950,16 +10298,30 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 		nargs++;
 	}
 
-	appendStringInfo(buf, "%s(",
-					 generate_function_name(wfunc->winfnoid, nargs,
-											argnames, argtypes,
-											false, NULL,
-											context->special_exprkind));
+	if (!funcname)
+		funcname = generate_function_name(wfunc->winfnoid, nargs, argnames,
+										  argtypes, false, NULL,
+										  context->special_exprkind);
+
+	appendStringInfo(buf, "%s(", funcname);
+
 	/* winstar can be set only in zero-argument aggregates */
 	if (wfunc->winstar)
 		appendStringInfoChar(buf, '*');
 	else
-		get_rule_expr((Node *) wfunc->args, context, true);
+	{
+		if (is_json_objectagg)
+		{
+			get_rule_expr((Node *) linitial(wfunc->args), context, false);
+			appendStringInfoString(buf, " : ");
+			get_rule_expr((Node *) lsecond(wfunc->args), context, false);
+		}
+		else
+			get_rule_expr((Node *) wfunc->args, context, true);
+	}
+
+	if (options)
+		appendStringInfoString(buf, options);
 
 	if (wfunc->aggfilter != NULL)
 	{
@@ -9996,6 +10358,15 @@ get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
 	}
 }
 
+/*
+ * get_windowfunc_expr	- Parse back a WindowFunc node
+ */
+static void
+get_windowfunc_expr(WindowFunc *wfunc, deparse_context *context)
+{
+	return get_windowfunc_expr_helper(wfunc, context, NULL, NULL, false);
+}
+
 /*
  * get_func_sql_syntax		- Parse back a SQL-syntax function call
  *
@@ -10236,6 +10607,31 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context)
 	return false;
 }
 
+/*
+ * get_json_agg_constructor - Parse back an aggregate JsonConstructorExpr node
+ */
+static void
+get_json_agg_constructor(JsonConstructorExpr *ctor, deparse_context *context,
+						 const char *funcname, bool is_json_objectagg)
+{
+	StringInfoData options;
+
+	initStringInfo(&options);
+	get_json_constructor_options(ctor, &options);
+
+	if (IsA(ctor->func, Aggref))
+		return get_agg_expr_helper((Aggref *) ctor->func, context,
+								   (Aggref *) ctor->func,
+								   funcname, options.data, is_json_objectagg);
+	else if (IsA(ctor->func, WindowFunc))
+		return get_windowfunc_expr_helper((WindowFunc *) ctor->func, context,
+										  funcname, options.data,
+										  is_json_objectagg);
+	else
+		elog(ERROR, "invalid JsonConstructorExpr underlying node type: %d",
+			 nodeTag(ctor->func));
+}
+
 /* ----------
  * get_coercion_expr
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index a67487e5fe..7120836c70 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -737,6 +737,75 @@ JumbleExpr(JumbleState *jstate, Node *node)
 				JumbleExpr(jstate, (Node *) conf->exclRelTlist);
 			}
 			break;
+		case T_JsonFormat:
+			{
+				JsonFormat *format = (JsonFormat *) node;
+
+				APP_JUMB(format->type);
+				APP_JUMB(format->encoding);
+			}
+			break;
+		case T_JsonReturning:
+			{
+				JsonReturning *returning = (JsonReturning *) node;
+
+				JumbleExpr(jstate, (Node *) returning->format);
+				APP_JUMB(returning->typid);
+				APP_JUMB(returning->typmod);
+			}
+			break;
+		case T_JsonValueExpr:
+			{
+				JsonValueExpr *expr = (JsonValueExpr *) node;
+
+				JumbleExpr(jstate, (Node *) expr->raw_expr);
+				JumbleExpr(jstate, (Node *) expr->formatted_expr);
+				JumbleExpr(jstate, (Node *) expr->format);
+			}
+			break;
+		case T_JsonConstructorExpr:
+			{
+				JsonConstructorExpr *ctor = (JsonConstructorExpr *) node;
+
+				JumbleExpr(jstate, (Node *) ctor->func);
+				JumbleExpr(jstate, (Node *) ctor->coercion);
+				JumbleExpr(jstate, (Node *) ctor->returning);
+				APP_JUMB(ctor->type);
+				APP_JUMB(ctor->unique);
+				APP_JUMB(ctor->absent_on_null);
+			}
+			break;
+		case T_JsonIsPredicate:
+			{
+				JsonIsPredicate *pred = (JsonIsPredicate *) node;
+
+				JumbleExpr(jstate, (Node *) pred->expr);
+				JumbleExpr(jstate, (Node *) pred->format);
+				APP_JUMB(pred->unique_keys);
+				APP_JUMB(pred->value_type);
+			}
+			break;
+		case T_JsonExpr:
+			{
+				JsonExpr    *jexpr = (JsonExpr *) node;
+
+				APP_JUMB(jexpr->op);
+				JumbleExpr(jstate, jexpr->formatted_expr);
+				JumbleExpr(jstate, jexpr->path_spec);
+				foreach(temp, jexpr->passing_names)
+				{
+					APP_JUMB_STRING(lfirst_node(String, temp)->sval);
+				}
+				JumbleExpr(jstate, (Node *) jexpr->passing_values);
+				if (jexpr->on_empty)
+				{
+					APP_JUMB(jexpr->on_empty->btype);
+					JumbleExpr(jstate, jexpr->on_empty->default_expr);
+				}
+				APP_JUMB(jexpr->on_error->btype);
+				JumbleExpr(jstate, jexpr->on_error->default_expr);
+			}
+			break;
 		case T_List:
 			foreach(temp, (List *) node)
 			{
diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat
index 2843f4b415..1934f19335 100644
--- a/src/include/catalog/pg_aggregate.dat
+++ b/src/include/catalog/pg_aggregate.dat
@@ -567,14 +567,36 @@
 # json
 { aggfnoid => 'json_agg', aggtransfn => 'json_agg_transfn',
   aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_agg_strict', aggtransfn => 'json_agg_strict_transfn',
+  aggfinalfn => 'json_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'json_object_agg', aggtransfn => 'json_object_agg_transfn',
   aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique',
+  aggtransfn => 'json_object_agg_unique_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_strict',
+  aggtransfn => 'json_object_agg_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'json_object_agg_unique_strict',
+  aggtransfn => 'json_object_agg_unique_strict_transfn',
+  aggfinalfn => 'json_object_agg_finalfn', aggtranstype => 'internal' },
 
 # jsonb
 { aggfnoid => 'jsonb_agg', aggtransfn => 'jsonb_agg_transfn',
   aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_agg_strict', aggtransfn => 'jsonb_agg_strict_transfn',
+  aggfinalfn => 'jsonb_agg_finalfn', aggtranstype => 'internal' },
 { aggfnoid => 'jsonb_object_agg', aggtransfn => 'jsonb_object_agg_transfn',
   aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique',
+  aggtransfn => 'jsonb_object_agg_unique_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_strict',
+  aggtransfn => 'jsonb_object_agg_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
+{ aggfnoid => 'jsonb_object_agg_unique_strict',
+  aggtransfn => 'jsonb_object_agg_unique_strict_transfn',
+  aggfinalfn => 'jsonb_object_agg_finalfn', aggtranstype => 'internal' },
 
 # ordered-set and hypothetical-set aggregates
 { aggfnoid => 'percentile_disc(float8,anyelement)', aggkind => 'o',
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 699bd0aa3e..5e612a6b67 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -8737,6 +8737,10 @@
   proname => 'json_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'json_agg_transfn' },
+{ oid => '8173', descr => 'json aggregate transition function',
+  proname => 'json_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'json_agg_strict_transfn' },
 { oid => '3174', descr => 'json aggregate final function',
   proname => 'json_agg_finalfn', proisstrict => 'f', prorettype => 'json',
   proargtypes => 'internal', prosrc => 'json_agg_finalfn' },
@@ -8744,10 +8748,26 @@
   proname => 'json_agg', prokind => 'a', proisstrict => 'f', provolatile => 's',
   prorettype => 'json', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8174', descr => 'aggregate input into json',
+  proname => 'json_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3180', descr => 'json object aggregate transition function',
   proname => 'json_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'json_object_agg_transfn' },
+{ oid => '8175', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_strict_transfn' },
+{ oid => '8176', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_transfn' },
+{ oid => '8177', descr => 'json object aggregate transition function',
+  proname => 'json_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal', proargtypes => 'internal any any',
+  prosrc => 'json_object_agg_unique_strict_transfn' },
 { oid => '3196', descr => 'json object aggregate final function',
   proname => 'json_object_agg_finalfn', proisstrict => 'f',
   prorettype => 'json', proargtypes => 'internal',
@@ -8756,6 +8776,19 @@
   proname => 'json_object_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8178', descr => 'aggregate non-NULL input into a json object',
+  proname => 'json_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8179', descr => 'aggregate input into a json object with unique keys',
+  proname => 'json_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'json', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8180',
+  descr => 'aggregate non-NULL input into a json object with unique keys',
+  proname => 'json_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', provolatile => 's', prorettype => 'json',
+  proargtypes => 'any any', prosrc => 'aggregate_dummy' },
 { oid => '3198', descr => 'build a json array from any inputs',
   proname => 'json_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'json', proargtypes => 'any',
@@ -9628,6 +9661,10 @@
   proname => 'jsonb_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal anyelement',
   prosrc => 'jsonb_agg_transfn' },
+{ oid => '8181', descr => 'jsonb aggregate transition function',
+  proname => 'jsonb_agg_strict_transfn', proisstrict => 'f', provolatile => 's',
+  prorettype => 'internal', proargtypes => 'internal anyelement',
+  prosrc => 'jsonb_agg_strict_transfn' },
 { oid => '3266', descr => 'jsonb aggregate final function',
   proname => 'jsonb_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9636,10 +9673,29 @@
   proname => 'jsonb_agg', prokind => 'a', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
   prosrc => 'aggregate_dummy' },
+{ oid => '8182', descr => 'aggregate input into jsonb skipping nulls',
+  proname => 'jsonb_agg_strict', prokind => 'a', proisstrict => 'f',
+  provolatile => 's', prorettype => 'jsonb', proargtypes => 'anyelement',
+  prosrc => 'aggregate_dummy' },
 { oid => '3268', descr => 'jsonb object aggregate transition function',
   proname => 'jsonb_object_agg_transfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'internal', proargtypes => 'internal any any',
   prosrc => 'jsonb_object_agg_transfn' },
+{ oid => '8183', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_strict_transfn' },
+{ oid => '8184', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_transfn' },
+{ oid => '8185', descr => 'jsonb object aggregate transition function',
+  proname => 'jsonb_object_agg_unique_strict_transfn', proisstrict => 'f',
+  provolatile => 's', prorettype => 'internal',
+  proargtypes => 'internal any any',
+  prosrc => 'jsonb_object_agg_unique_strict_transfn' },
 { oid => '3269', descr => 'jsonb object aggregate final function',
   proname => 'jsonb_object_agg_finalfn', proisstrict => 'f', provolatile => 's',
   prorettype => 'jsonb', proargtypes => 'internal',
@@ -9648,6 +9704,20 @@
   proname => 'jsonb_object_agg', prokind => 'a', proisstrict => 'f',
   prorettype => 'jsonb', proargtypes => 'any any',
   prosrc => 'aggregate_dummy' },
+{ oid => '8186', descr => 'aggregate non-NULL inputs into jsonb object',
+  proname => 'jsonb_object_agg_strict', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8187',
+  descr => 'aggregate inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique', prokind => 'a', proisstrict => 'f',
+  prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
+{ oid => '8188',
+  descr => 'aggregate non-NULL inputs into jsonb object checking key uniqueness',
+  proname => 'jsonb_object_agg_unique_strict', prokind => 'a',
+  proisstrict => 'f', prorettype => 'jsonb', proargtypes => 'any any',
+  prosrc => 'aggregate_dummy' },
 { oid => '3271', descr => 'build a jsonb array from any inputs',
   proname => 'jsonb_build_array', provariadic => 'any', proisstrict => 'f',
   provolatile => 's', prorettype => 'jsonb', proargtypes => 'any',
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 56a89ebafb..9ce8df17e5 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -21,6 +21,7 @@
 struct ExprEvalStep;
 struct SubscriptingRefState;
 struct ScalarArrayOpExprHashTable;
+struct JsonbValue;
 
 /* Bits in ExprState->flags (see also execnodes.h for public flag bits): */
 /* expression's interpreter has been initialized */
@@ -239,6 +240,9 @@ typedef enum ExprEvalOp
 	EEOP_GROUPING_FUNC,
 	EEOP_WINDOW_FUNC,
 	EEOP_SUBPLAN,
+	EEOP_JSON_CONSTRUCTOR,
+	EEOP_IS_JSON,
+	EEOP_JSONEXPR,
 
 	/* aggregation related nodes */
 	EEOP_AGG_STRICT_DESERIALIZE,
@@ -668,6 +672,72 @@ typedef struct ExprEvalStep
 			int			transno;
 			int			setoff;
 		}			agg_trans;
+
+		/* for EEOP_JSON_CONSTRUCTOR */
+		struct
+		{
+			JsonConstructorExpr *constructor;
+			Datum	   *arg_values;
+			bool	   *arg_nulls;
+			Oid		   *arg_types;
+			struct
+			{
+				int			category;
+				Oid			outfuncid;
+			}		   *arg_type_cache;		/* cache for datum_to_json[b]() */
+			int			nargs;
+		}			json_constructor;
+
+		/* for EEOP_IS_JSON */
+		struct
+		{
+					JsonIsPredicate *pred;	/* original expression node */
+		}			is_json;
+
+		/* for EEOP_JSONEXPR */
+		struct
+		{
+			JsonExpr   *jsexpr;			/* original expression node */
+
+			struct
+			{
+				FmgrInfo	func;		/* typinput function for output type */
+				Oid			typioparam;
+			} input;					/* I/O info for output type */
+
+			NullableDatum
+					   *formatted_expr,		/* formatted context item value */
+					   *res_expr,			/* result item */
+					   *coercion_expr,		/* input for JSON item coercion */
+					   *pathspec;			/* path specification value */
+
+			ExprState  *result_expr;		/* coerced to output type */
+			ExprState  *default_on_empty;	/* ON EMPTY DEFAULT expression */
+			ExprState  *default_on_error;	/* ON ERROR DEFAULT expression */
+			List	   *args;				/* passing arguments */
+
+			void	   *cache;				/* cache for json_populate_type() */
+
+			struct JsonCoercionsState
+			{
+				struct JsonCoercionState
+				{
+					JsonCoercion *coercion;		/* coercion expression */
+					ExprState  *estate;	/* coercion expression state */
+				} 			null,
+							string,
+							numeric,
+							boolean,
+							date,
+							time,
+							timetz,
+							timestamp,
+							timestamptz,
+							composite;
+			}			coercions;	/* states for coercion from SQL/JSON item
+									 * types directly to the output type */
+		}			jsonexpr;
+
 	}			d;
 } ExprEvalStep;
 
@@ -762,6 +832,7 @@ extern void ExecEvalHashedScalarArrayOp(ExprState *state, ExprEvalStep *op,
 extern void ExecEvalConstraintNotNull(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalConstraintCheck(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op);
+extern void ExecEvalJsonIsPredicate(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalGroupingFunc(ExprState *state, ExprEvalStep *op);
 extern void ExecEvalSubPlan(ExprState *state, ExprEvalStep *op,
 							ExprContext *econtext);
@@ -769,6 +840,16 @@ extern void ExecEvalWholeRowVar(ExprState *state, ExprEvalStep *op,
 								ExprContext *econtext);
 extern void ExecEvalSysVar(ExprState *state, ExprEvalStep *op,
 						   ExprContext *econtext, TupleTableSlot *slot);
+extern void ExecEvalJsonConstructor(ExprState *state, ExprEvalStep *op,
+									ExprContext *econtext);
+extern void ExecEvalJson(ExprState *state, ExprEvalStep *op,
+						 ExprContext *econtext);
+extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
+										 JsonReturning *returning,
+										 struct JsonCoercionsState *coercions,
+										 struct JsonCoercionState **pjcstate);
+extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
+											struct JsonCoercionsState *);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h
index 82925b4b63..873772f188 100644
--- a/src/include/executor/executor.h
+++ b/src/include/executor/executor.h
@@ -265,6 +265,8 @@ ExecProcNode(PlanState *node)
  */
 extern ExprState *ExecInitExpr(Expr *node, PlanState *parent);
 extern ExprState *ExecInitExprWithParams(Expr *node, ParamListInfo ext_params);
+extern ExprState *ExecInitExprWithCaseValue(Expr *node, PlanState *parent,
+						  Datum *caseval, bool *casenull);
 extern ExprState *ExecInitQual(List *qual, PlanState *parent);
 extern ExprState *ExecInitCheck(List *qual, PlanState *parent);
 extern List *ExecInitExprList(List *nodes, PlanState *parent);
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 50de4c62af..872f2f0828 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -106,4 +106,14 @@ extern GroupingSet *makeGroupingSet(GroupingSetKind kind, List *content, int loc
 
 extern VacuumRelation *makeVacuumRelation(RangeVar *relation, Oid oid, List *va_cols);
 
+extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
+								  int location);
+extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
+extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonKeyValue(Node *key, Node *value);
+extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
+								 JsonValueType vtype, bool unique_keys,
+								 int location);
+extern JsonEncoding makeJsonEncoding(char *name);
+
 #endif							/* MAKEFUNC_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 5d075f0c34..37deb134b9 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -201,6 +201,16 @@ typedef enum NodeTag
 	T_FromExpr,
 	T_OnConflictExpr,
 	T_IntoClause,
+	T_JsonFormat,
+	T_JsonReturning,
+	T_JsonValueExpr,
+	T_JsonParseExpr,
+	T_JsonScalarExpr,
+	T_JsonSerializeExpr,
+	T_JsonConstructorExpr,
+	T_JsonExpr,
+	T_JsonCoercion,
+	T_JsonItemCoercions,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -491,6 +501,19 @@ typedef enum NodeTag
 	T_VacuumRelation,
 	T_PublicationObjSpec,
 	T_PublicationTable,
+	T_JsonObjectConstructor,
+	T_JsonArrayConstructor,
+	T_JsonArrayQueryConstructor,
+	T_JsonAggConstructor,
+	T_JsonObjectAgg,
+	T_JsonArrayAgg,
+	T_JsonFuncExpr,
+	T_JsonIsPredicate,
+	T_JsonCommon,
+	T_JsonArgument,
+	T_JsonKeyValue,
+	T_JsonBehavior,
+	T_JsonOutput,
 
 	/*
 	 * TAGS FOR REPLICATION GRAMMAR PARSE NODES (replnodes.h)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index cb1fcc0ee3..60cceb9bdc 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1553,6 +1553,209 @@ typedef struct TriggerTransition
 	bool		isTable;
 } TriggerTransition;
 
+/* Nodes for SQL/JSON support */
+
+/*
+ * JsonQuotes -
+ *		representation of [KEEP|OMIT] QUOTES clause for JSON_QUERY()
+ */
+typedef enum JsonQuotes
+{
+	JS_QUOTES_UNSPEC,			/* unspecified */
+	JS_QUOTES_KEEP,				/* KEEP QUOTES */
+	JS_QUOTES_OMIT				/* OMIT QUOTES */
+} JsonQuotes;
+
+/*
+ * JsonPathSpec -
+ *		representation of JSON path constant
+ */
+typedef char *JsonPathSpec;
+
+/*
+ * JsonOutput -
+ *		representation of JSON output clause (RETURNING type [FORMAT format])
+ */
+typedef struct JsonOutput
+{
+	NodeTag		type;
+	TypeName   *typeName;		/* RETURNING type name, if specified */
+	JsonReturning *returning;	/* RETURNING FORMAT clause and type Oids */
+} JsonOutput;
+
+/*
+ * JsonArgument -
+ *		representation of argument from JSON PASSING clause
+ */
+typedef struct JsonArgument
+{
+	NodeTag		type;
+	JsonValueExpr *val;			/* argument value expression */
+	char	   *name;			/* argument name */
+} JsonArgument;
+
+/*
+ * JsonCommon -
+ *		representation of common syntax of functions using JSON path
+ */
+typedef struct JsonCommon
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* context item expression */
+	Node	   *pathspec;		/* JSON path specification expression */
+	char	   *pathname;		/* path name, if any */
+	List	   *passing;		/* list of PASSING clause arguments, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonCommon;
+
+/*
+ * JsonFuncExpr -
+ *		untransformed representation of JSON function expressions
+ */
+typedef struct JsonFuncExpr
+{
+	NodeTag		type;
+	JsonExprOp	op;				/* expression type */
+	JsonCommon *common;			/* common syntax */
+	JsonOutput *output;			/* output clause, if specified */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior, if specified */
+	JsonBehavior *on_error;		/* ON ERROR behavior, if specified */
+	JsonWrapper	wrapper;		/* array wrapper behavior (JSON_QUERY only) */
+	bool		omit_quotes;	/* omit or keep quotes? (JSON_QUERY only) */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFuncExpr;
+
+/*
+ * JsonKeyValue -
+ *		untransformed representation of JSON object key-value pair for
+ *		JSON_OBJECT() and JSON_OBJECTAGG()
+ */
+typedef struct JsonKeyValue
+{
+	NodeTag		type;
+	Expr	   *key;			/* key expression */
+	JsonValueExpr *value;		/* JSON value expression */
+} JsonKeyValue;
+
+/*
+ * JsonParseExpr -
+ *		untransformed representation of JSON()
+ */
+typedef struct JsonParseExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* string expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	bool		unique_keys;	/* WITH UNIQUE KEYS? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonParseExpr;
+
+/*
+ * JsonScalarExpr -
+ *		untransformed representation of JSON_SCALAR()
+ */
+typedef struct JsonScalarExpr
+{
+	NodeTag		type;
+	Expr	   *expr;			/* scalar expression */
+	JsonOutput *output;			/* RETURNING clause, if specified */
+	int			location;		/* token location, or -1 if unknown */
+} JsonScalarExpr;
+
+/*
+ * JsonSerializeExpr -
+ *		untransformed representation of JSON_SERIALIZE() function
+ */
+typedef struct JsonSerializeExpr
+{
+	NodeTag		type;
+	JsonValueExpr *expr;		/* json value expression */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	int			location;		/* token location, or -1 if unknown */
+} JsonSerializeExpr;
+
+/*
+ * JsonObjectConstructor -
+ *		untransformed representation of JSON_OBJECT() constructor
+ */
+typedef struct JsonObjectConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonKeyValue pairs */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonObjectConstructor;
+
+/*
+ * JsonArrayConstructor -
+ *		untransformed representation of JSON_ARRAY(element,...) constructor
+ */
+typedef struct JsonArrayConstructor
+{
+	NodeTag		type;
+	List	   *exprs;			/* list of JsonValueExpr elements */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayConstructor;
+
+/*
+ * JsonArrayQueryConstructor -
+ *		untransformed representation of JSON_ARRAY(subquery) constructor
+ */
+typedef struct JsonArrayQueryConstructor
+{
+	NodeTag		type;
+	Node	   *query;			/* subquery */
+	JsonOutput *output;			/* RETURNING clause, if specified  */
+	JsonFormat *format;			/* FORMAT clause for subquery, if specified */
+	bool		absent_on_null;	/* skip NULL elements? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonArrayQueryConstructor;
+
+/*
+ * JsonAggConstructor -
+ *		common fields of untransformed representation of
+ *		JSON_ARRAYAGG() and JSON_OBJECTAGG()
+ */
+typedef struct JsonAggConstructor
+{
+	NodeTag		type;
+	JsonOutput *output;			/* RETURNING clause, if any */
+	Node	   *agg_filter;		/* FILTER clause, if any */
+	List	   *agg_order;		/* ORDER BY clause, if any */
+	struct WindowDef *over;		/* OVER clause, if any */
+	int			location;		/* token location, or -1 if unknown */
+} JsonAggConstructor;
+
+/*
+ * JsonObjectAgg -
+ *		untransformed representation of JSON_OBJECTAGG()
+ */
+typedef struct JsonObjectAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonKeyValue *arg;			/* object key-value pair */
+	bool		absent_on_null;	/* skip NULL values? */
+	bool		unique;			/* check key uniqueness? */
+} JsonObjectAgg;
+
+/*
+ * JsonArrayAgg -
+ *		untransformed representation of JSON_ARRRAYAGG()
+ */
+typedef struct JsonArrayAgg
+{
+	NodeTag		type;
+	JsonAggConstructor *constructor; /* common fields */
+	JsonValueExpr *arg;			/* array element expression */
+	bool		absent_on_null;	/* skip NULL elements? */
+} JsonArrayAgg;
+
+
 /*****************************************************************************
  *		Raw Grammar Output Statements
  *****************************************************************************/
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 439e4b4a9d..cc28c20c0e 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1233,6 +1233,228 @@ typedef struct XmlExpr
 	int			location;		/* token location, or -1 if unknown */
 } XmlExpr;
 
+/*
+ * JsonExprOp -
+ *		enumeration of JSON functions using JSON path
+ */
+typedef enum JsonExprOp
+{
+	IS_JSON_VALUE,				/* JSON_VALUE() */
+	IS_JSON_QUERY,				/* JSON_QUERY() */
+	IS_JSON_EXISTS				/* JSON_EXISTS() */
+} JsonExprOp;
+
+/*
+ * JsonEncoding -
+ *		representation of JSON ENCODING clause
+ */
+typedef enum JsonEncoding
+{
+	JS_ENC_DEFAULT,				/* unspecified */
+	JS_ENC_UTF8,
+	JS_ENC_UTF16,
+	JS_ENC_UTF32,
+} JsonEncoding;
+
+/*
+ * JsonFormatType -
+ *		enumeration of JSON formats used in JSON FORMAT clause
+ */
+typedef enum JsonFormatType
+{
+	JS_FORMAT_DEFAULT,			/* unspecified */
+	JS_FORMAT_JSON,				/* FORMAT JSON [ENCODING ...] */
+	JS_FORMAT_JSONB				/* implicit internal format for RETURNING jsonb */
+} JsonFormatType;
+
+/*
+ * JsonBehaviorType -
+ *		enumeration of behavior types used in JSON ON ... BEHAVIOR clause
+ *
+ * 		If enum members are reordered, get_json_behavior() from ruleutils.c
+ * 		must be updated accordingly.
+ */
+typedef enum JsonBehaviorType
+{
+	JSON_BEHAVIOR_NULL = 0,
+	JSON_BEHAVIOR_ERROR,
+	JSON_BEHAVIOR_EMPTY,
+	JSON_BEHAVIOR_TRUE,
+	JSON_BEHAVIOR_FALSE,
+	JSON_BEHAVIOR_UNKNOWN,
+	JSON_BEHAVIOR_EMPTY_ARRAY,
+	JSON_BEHAVIOR_EMPTY_OBJECT,
+	JSON_BEHAVIOR_DEFAULT
+} JsonBehaviorType;
+
+/*
+ * JsonWrapper -
+ *		representation of WRAPPER clause for JSON_QUERY()
+ */
+typedef enum JsonWrapper
+{
+	JSW_NONE,
+	JSW_CONDITIONAL,
+	JSW_UNCONDITIONAL,
+} JsonWrapper;
+
+/*
+ * JsonFormat -
+ *		representation of JSON FORMAT clause
+ */
+typedef struct JsonFormat
+{
+	NodeTag		type;
+	JsonFormatType format_type;	/* format type */
+	JsonEncoding encoding;		/* JSON encoding */
+	int			location;		/* token location, or -1 if unknown */
+} JsonFormat;
+
+/*
+ * JsonReturning -
+ *		transformed representation of JSON RETURNING clause
+ */
+typedef struct JsonReturning
+{
+	NodeTag		type;
+	JsonFormat *format;			/* output JSON format */
+	Oid			typid;			/* target type Oid */
+	int32		typmod;			/* target type modifier */
+} JsonReturning;
+
+/*
+ * JsonValueExpr -
+ *		representation of JSON value expression (expr [FORMAT json_format])
+ */
+typedef struct JsonValueExpr
+{
+	NodeTag		type;
+	Expr	   *raw_expr;		/* raw expression */
+	Expr	   *formatted_expr;	/* formatted expression or NULL */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+} JsonValueExpr;
+
+typedef enum JsonConstructorType
+{
+	JSCTOR_JSON_OBJECT = 1,
+	JSCTOR_JSON_ARRAY = 2,
+	JSCTOR_JSON_OBJECTAGG = 3,
+	JSCTOR_JSON_ARRAYAGG = 4,
+	JSCTOR_JSON_SCALAR = 5,
+	JSCTOR_JSON_SERIALIZE = 6,
+	JSCTOR_JSON_PARSE = 7
+} JsonConstructorType;
+
+/*
+ * JsonConstructorExpr -
+ *		wrapper over FuncExpr/Aggref/WindowFunc for SQL/JSON constructors
+ */
+typedef struct JsonConstructorExpr
+{
+	Expr		xpr;
+	JsonConstructorType type;	/* constructor type */
+	List	   *args;
+	Expr	   *func;			/* underlying json[b]_xxx() function call */
+	Expr	   *coercion;		/* coercion to RETURNING type */
+	JsonReturning *returning;	/* RETURNING clause */
+	bool		absent_on_null;	/* ABSENT ON NULL? */
+	bool		unique;			/* WITH UNIQUE KEYS? (JSON_OBJECT[AGG] only) */
+	int			location;
+} JsonConstructorExpr;
+
+/*
+ * JsonValueType -
+ *		representation of JSON item type in IS JSON predicate
+ */
+typedef enum JsonValueType
+{
+	JS_TYPE_ANY,				/* IS JSON [VALUE] */
+	JS_TYPE_OBJECT,				/* IS JSON OBJECT */
+	JS_TYPE_ARRAY,				/* IS JSON ARRAY*/
+	JS_TYPE_SCALAR				/* IS JSON SCALAR */
+} JsonValueType;
+
+/*
+ * JsonIsPredicate -
+ *		untransformed representation of IS JSON predicate
+ */
+typedef struct JsonIsPredicate
+{
+	NodeTag		type;
+	Node	   *expr;			/* untransformed expression */
+	JsonFormat *format;			/* FORMAT clause, if specified */
+	JsonValueType value_type;	/* JSON item type */
+	bool		unique_keys;	/* check key uniqueness? */
+	int			location;		/* token location, or -1 if unknown */
+} JsonIsPredicate;
+
+/*
+ * JsonBehavior -
+ *		representation of JSON ON ... BEHAVIOR clause
+ */
+typedef struct JsonBehavior
+{
+	NodeTag		type;
+	JsonBehaviorType btype;		/* behavior type */
+	Node	   *default_expr;	/* default expression, if any */
+} JsonBehavior;
+
+/*
+ * JsonCoercion -
+ *		coercion from SQL/JSON item types to SQL types
+ */
+typedef struct JsonCoercion
+{
+	NodeTag		type;
+	Node	   *expr;			/* resulting expression coerced to target type */
+	bool		via_populate;	/* coerce result using json_populate_type()? */
+	bool		via_io;			/* coerce result using type input function? */
+	Oid			collation;		/* collation for coercion via I/O or populate */
+} JsonCoercion;
+
+/*
+ * JsonItemCoercions -
+ *		expressions for coercion from SQL/JSON item types directly to the
+ *		output SQL type
+ */
+typedef struct JsonItemCoercions
+{
+	NodeTag		type;
+	JsonCoercion *null;
+	JsonCoercion *string;
+	JsonCoercion *numeric;
+	JsonCoercion *boolean;
+	JsonCoercion *date;
+	JsonCoercion *time;
+	JsonCoercion *timetz;
+	JsonCoercion *timestamp;
+	JsonCoercion *timestamptz;
+	JsonCoercion *composite;	/* arrays and objects */
+} JsonItemCoercions;
+
+/*
+ * JsonExpr -
+ *		transformed representation of JSON_VALUE(), JSON_QUERY(), JSON_EXISTS()
+ */
+typedef struct JsonExpr
+{
+	Expr		xpr;
+	JsonExprOp	op;				/* json function ID */
+	Node	   *formatted_expr;	/* formatted context item expression */
+	JsonCoercion *result_coercion;	/* resulting coercion to RETURNING type */
+	JsonFormat *format;			/* context item format (JSON/JSONB) */
+	Node	   *path_spec;		/* JSON path specification expression */
+	List	   *passing_names;	/* PASSING argument names */
+	List	   *passing_values;	/* PASSING argument values */
+	JsonReturning *returning;	/* RETURNING clause type/format info */
+	JsonBehavior *on_empty;		/* ON EMPTY behavior */
+	JsonBehavior *on_error;		/* ON ERROR behavior */
+	JsonItemCoercions *coercions; /* coercions for JSON_VALUE */
+	JsonWrapper	wrapper;		/* WRAPPER for JSON_QUERY */
+	bool		omit_quotes;	/* KEEP/OMIT QUOTES for JSON_QUERY */
+	int			location;		/* token location, or -1 if unknown */
+} JsonExpr;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index bcef7eed2f..ab3d8e0b52 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -26,6 +26,7 @@
 
 /* name, value, category, is-bare-label */
 PG_KEYWORD("abort", ABORT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("absent", ABSENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("absolute", ABSOLUTE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("access", ACCESS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("action", ACTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -92,6 +93,7 @@ PG_KEYWORD("commit", COMMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("committed", COMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("compression", COMPRESSION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("concurrently", CONCURRENTLY, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("conditional", CONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("configuration", CONFIGURATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("conflict", CONFLICT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("connection", CONNECTION, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -146,11 +148,13 @@ PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("empty", EMPTY_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encoding", ENCODING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("encrypted", ENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("end", END_P, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enum", ENUM_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("error", ERROR_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("escape", ESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("event", EVENT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("except", EXCEPT, RESERVED_KEYWORD, AS_LABEL)
@@ -175,6 +179,7 @@ PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("for", FOR, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("force", FORCE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("foreign", FOREIGN, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("format", FORMAT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("forward", FORWARD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("from", FROM, RESERVED_KEYWORD, AS_LABEL)
@@ -227,7 +232,19 @@ PG_KEYWORD("is", IS, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("isnull", ISNULL, TYPE_FUNC_NAME_KEYWORD, AS_LABEL)
 PG_KEYWORD("isolation", ISOLATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("join", JOIN, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json", JSON, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_array", JSON_ARRAY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_arrayagg", JSON_ARRAYAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_exists", JSON_EXISTS, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_object", JSON_OBJECT, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("keys", KEYS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("label", LABEL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("language", LANGUAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("large", LARGE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -289,6 +306,7 @@ PG_KEYWORD("off", OFF, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("offset", OFFSET, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("oids", OIDS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("old", OLD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("omit", OMIT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("on", ON, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("only", ONLY, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("operator", OPERATOR, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +348,7 @@ PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("quotes", QUOTES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("range", RANGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("read", READ, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("real", REAL, COL_NAME_KEYWORD, BARE_LABEL)
@@ -364,6 +383,7 @@ PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("scalar", SCALAR, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schema", SCHEMA, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("schemas", SCHEMAS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("scroll", SCROLL, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -399,6 +419,7 @@ PG_KEYWORD("stdout", STDOUT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("storage", STORAGE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("stored", STORED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strict", STRICT_P, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("string", STRING, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("strip", STRIP_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("subscription", SUBSCRIPTION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("substring", SUBSTRING, COL_NAME_KEYWORD, BARE_LABEL)
@@ -433,6 +454,7 @@ PG_KEYWORD("types", TYPES_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uescape", UESCAPE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unbounded", UNBOUNDED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("uncommitted", UNCOMMITTED, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("unconditional", UNCONDITIONAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("unencrypted", UNENCRYPTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("union", UNION, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("unique", UNIQUE, RESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h
index 851e787bfd..0a22af80a2 100644
--- a/src/include/utils/formatting.h
+++ b/src/include/utils/formatting.h
@@ -17,6 +17,9 @@
 #ifndef _FORMATTING_H_
 #define _FORMATTING_H_
 
+#define DCH_DATED	0x01
+#define DCH_TIMED	0x02
+#define DCH_ZONED	0x04
 
 extern char *str_tolower(const char *buff, size_t nbytes, Oid collid);
 extern char *str_toupper(const char *buff, size_t nbytes, Oid collid);
@@ -29,5 +32,6 @@ extern char *asc_initcap(const char *buff, size_t nbytes);
 extern Datum parse_datetime(text *date_txt, text *fmt, Oid collid, bool strict,
 							Oid *typid, int32 *typmod, int *tz,
 							bool *have_error);
+extern int datetime_format_flags(const char *fmt_str, bool *have_error);
 
 #endif
diff --git a/src/include/utils/json.h b/src/include/utils/json.h
index 8a84a0cdb4..da4a9257b3 100644
--- a/src/include/utils/json.h
+++ b/src/include/utils/json.h
@@ -16,9 +16,35 @@
 
 #include "lib/stringinfo.h"
 
+typedef enum					/* type categories for datum_to_json */
+{
+	JSONTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONTYPE_TIMESTAMP,
+	JSONTYPE_TIMESTAMPTZ,
+	JSONTYPE_JSON,				/* JSON itself (and JSONB) */
+	JSONTYPE_ARRAY,				/* array */
+	JSONTYPE_COMPOSITE,			/* composite */
+	JSONTYPE_CAST,				/* something with an explicit cast to JSON */
+	JSONTYPE_OTHER				/* all else */
+} JsonTypeCategory;
+
 /* functions in json.c */
 extern void escape_json(StringInfo buf, const char *str);
 extern char *JsonEncodeDateTime(char *buf, Datum value, Oid typid,
 								const int *tzp);
+extern bool to_json_is_immutable(Oid typoid);
+extern void json_categorize_type(Oid typoid, JsonTypeCategory *tcategory,
+								 Oid *outfuncoid);
+extern Datum to_json_worker(Datum val, JsonTypeCategory tcategory,
+							Oid outfuncoid);
+extern Datum json_build_object_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null,
+									  bool unique_keys);
+extern Datum json_build_array_worker(int nargs, Datum *args, bool *nulls,
+									 Oid *types, bool absent_on_null);
+extern bool json_validate(text *json, bool check_unique_keys, bool throw_error);
 
 #endif							/* JSON_H */
diff --git a/src/include/utils/jsonb.h b/src/include/utils/jsonb.h
index 4cbe6edf21..bae466b523 100644
--- a/src/include/utils/jsonb.h
+++ b/src/include/utils/jsonb.h
@@ -329,6 +329,8 @@ typedef struct JsonbParseState
 	JsonbValue	contVal;
 	Size		size;
 	struct JsonbParseState *next;
+	bool		unique_keys;	/* Check object key uniqueness */
+	bool		skip_nulls;		/* Skip null object fields */
 } JsonbParseState;
 
 /*
@@ -374,6 +376,22 @@ typedef struct JsonbIterator
 	struct JsonbIterator *parent;
 } JsonbIterator;
 
+/* unlike with json categories, we need to treat json and jsonb differently */
+typedef enum					/* type categories for datum_to_jsonb */
+{
+	JSONBTYPE_NULL,				/* null, so we didn't bother to identify */
+	JSONBTYPE_BOOL,				/* boolean (built-in types only) */
+	JSONBTYPE_NUMERIC,			/* numeric (ditto) */
+	JSONBTYPE_DATE,				/* we use special formatting for datetimes */
+	JSONBTYPE_TIMESTAMP,		/* we use special formatting for timestamp */
+	JSONBTYPE_TIMESTAMPTZ,		/* ... and timestamptz */
+	JSONBTYPE_JSON,				/* JSON */
+	JSONBTYPE_JSONB,			/* JSONB */
+	JSONBTYPE_ARRAY,			/* array */
+	JSONBTYPE_COMPOSITE,		/* composite */
+	JSONBTYPE_JSONCAST,			/* something with an explicit cast to JSON */
+	JSONBTYPE_OTHER				/* all else */
+} JsonbTypeCategory;
 
 /* Support functions */
 extern uint32 getJsonbOffset(const JsonbContainer *jc, int index);
@@ -401,10 +419,14 @@ extern void JsonbHashScalarValueExtended(const JsonbValue *scalarVal,
 										 uint64 *hash, uint64 seed);
 
 /* jsonb.c support functions */
+extern Datum jsonb_from_text(text *js, bool unique_keys);
 extern char *JsonbToCString(StringInfo out, JsonbContainer *in,
 							int estimated_len);
 extern char *JsonbToCStringIndent(StringInfo out, JsonbContainer *in,
 								  int estimated_len);
+extern Jsonb *JsonbMakeEmptyArray(void);
+extern Jsonb *JsonbMakeEmptyObject(void);
+extern char *JsonbUnquote(Jsonb *jb);
 extern bool JsonbExtractScalar(JsonbContainer *jbc, JsonbValue *res);
 extern const char *JsonbTypeName(JsonbValue *jb);
 
@@ -412,4 +434,15 @@ extern Datum jsonb_set_element(Jsonb *jb, Datum *path, int path_len,
 							   JsonbValue *newval);
 extern Datum jsonb_get_element(Jsonb *jb, Datum *path, int npath,
 							   bool *isnull, bool as_text);
+extern bool to_jsonb_is_immutable(Oid typoid);
+extern void jsonb_categorize_type(Oid typoid, JsonbTypeCategory *tcategory,
+								  Oid *outfuncoid);
+extern Datum to_jsonb_worker(Datum val, JsonbTypeCategory tcategory,
+							 Oid outfuncoid);
+extern Datum jsonb_build_object_worker(int nargs, Datum *args, bool *nulls,
+									   Oid *types, bool absent_on_null,
+									   bool unique_keys);
+extern Datum jsonb_build_array_worker(int nargs, Datum *args, bool *nulls,
+									  Oid *types, bool absent_on_null);
+
 #endif							/* __JSONB_H__ */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 865b2ff7c1..62dc3d88a4 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -45,6 +45,9 @@ extern void pg_parse_json_or_ereport(JsonLexContext *lex, JsonSemAction *sem);
 /* report an error during json lexing or parsing */
 extern void json_ereport_error(JsonParseErrorType error, JsonLexContext *lex);
 
+/* get first JSON token */
+extern JsonTokenType json_get_first_token(text *json, bool throw_error);
+
 extern uint32 parse_jsonb_index_flags(Jsonb *jb);
 extern void iterate_jsonb_values(Jsonb *jb, uint32 flags, void *state,
 								 JsonIterateStringValuesAction action);
@@ -55,4 +58,8 @@ extern Jsonb *transform_jsonb_string_values(Jsonb *jsonb, void *action_state,
 extern text *transform_json_string_values(text *json, void *action_state,
 										  JsonTransformStringValuesAction transform_action);
 
+extern Datum json_populate_type(Datum json_val, Oid json_type,
+								Oid typid, int32 typmod,
+								void **cache, MemoryContext mcxt, bool *isnull);
+
 #endif
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index cd0b5d5b61..98a61d7f72 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -16,7 +16,9 @@
 
 #include "fmgr.h"
 #include "nodes/pg_list.h"
+#include "nodes/primnodes.h"
 #include "utils/jsonb.h"
+#include "utils/jsonfuncs.h"
 
 typedef struct
 {
@@ -174,6 +176,7 @@ extern bool jspGetBool(JsonPathItem *v);
 extern char *jspGetString(JsonPathItem *v, int32 *len);
 extern bool jspGetArraySubscript(JsonPathItem *v, JsonPathItem *from,
 								 JsonPathItem *to, int i);
+extern bool jspIsMutable(JsonPath *path, List *varnames, List *varexprs);
 
 extern const char *jspOperationName(JsonPathItemType type);
 
@@ -248,4 +251,34 @@ extern JsonPathParseResult *parsejsonpath(const char *str, int len);
 
 extern int	jspConvertRegexFlags(uint32 xflags);
 
+/*
+ * Evaluation of jsonpath
+ */
+
+/* External variable passed into jsonpath. */
+typedef struct JsonPathVariableEvalContext
+{
+	char	   *name;
+	Oid			typid;
+	int32		typmod;
+	struct ExprContext *econtext;
+	struct ExprState  *estate;
+	Datum		value;
+	bool		isnull;
+	bool		evaluated;
+} JsonPathVariableEvalContext;
+
+/* SQL/JSON item */
+extern void JsonItemFromDatum(Datum val, Oid typid, int32 typmod,
+							  JsonbValue *res);
+
+extern bool  JsonPathExists(Datum jb, JsonPath *path, List *vars, bool *error);
+extern Datum JsonPathQuery(Datum jb, JsonPath *jp, JsonWrapper wrapper,
+						   bool *empty, bool *error, List *vars);
+extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
+								 bool *error, List *vars);
+
+extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
+						   JsonbValue *val, JsonbValue *baseObject);
+
 #endif
diff --git a/src/interfaces/ecpg/preproc/parse.pl b/src/interfaces/ecpg/preproc/parse.pl
index dee6b8200d..5ec511fd01 100644
--- a/src/interfaces/ecpg/preproc/parse.pl
+++ b/src/interfaces/ecpg/preproc/parse.pl
@@ -47,6 +47,8 @@ my %replace_string = (
 	'NOT_LA'         => 'not',
 	'NULLS_LA'       => 'nulls',
 	'WITH_LA'        => 'with',
+	'WITH_LA_UNIQUE' => 'with',
+	'WITHOUT_LA'     => 'without',
 	'TYPECAST'       => '::',
 	'DOT_DOT'        => '..',
 	'COLON_EQUALS'   => ':=',
diff --git a/src/interfaces/ecpg/preproc/parser.c b/src/interfaces/ecpg/preproc/parser.c
index a44e07a17a..5e2b606f9b 100644
--- a/src/interfaces/ecpg/preproc/parser.c
+++ b/src/interfaces/ecpg/preproc/parser.c
@@ -83,6 +83,7 @@ filtered_base_yylex(void)
 		case WITH:
 		case UIDENT:
 		case USCONST:
+		case WITHOUT:
 			break;
 		default:
 			return cur_token;
@@ -143,6 +144,19 @@ filtered_base_yylex(void)
 				case ORDINALITY:
 					cur_token = WITH_LA;
 					break;
+				case UNIQUE:
+					cur_token = WITH_LA_UNIQUE;
+					break;
+			}
+			break;
+
+		case WITHOUT:
+			/* Replace WITHOUT by WITHOUT_LA if it's followed by TIME */
+			switch (next_token)
+			{
+				case TIME:
+					cur_token = WITHOUT_LA;
+					break;
 			}
 			break;
 		case UIDENT:
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
new file mode 100644
index 0000000000..bb62634314
--- /dev/null
+++ b/src/test/regress/expected/json_sqljson.out
@@ -0,0 +1,15 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+ERROR:  JSON_EXISTS() is not yet implemented for json type
+LINE 1: SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+ERROR:  JSON_VALUE() is not yet implemented for json type
+LINE 1: SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+               ^
+-- JSON_QUERY
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+ERROR:  JSON_QUERY() is not yet implemented for json type
+LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+               ^
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
new file mode 100644
index 0000000000..1126d7caf5
--- /dev/null
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -0,0 +1,1018 @@
+-- JSON_EXISTS
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+ json_exists 
+-------------
+ 
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb 'null', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+ json_exists 
+-------------
+ f
+(1 row)
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+ json_exists 
+-------------
+ t
+(1 row)
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+ json_exists 
+-------------
+ f
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+ json_exists 
+-------------
+           1
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+ json_exists 
+-------------
+           0
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+ json_exists 
+-------------
+ true
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+ json_exists 
+-------------
+ false
+(1 row)
+
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+               ^
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+ERROR:  cannot cast type boolean to real
+LINE 1: SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+               ^
+-- JSON_VALUE
+SELECT JSON_VALUE(NULL::jsonb, '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+ json_value 
+------------
+ true
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+ json_value 
+------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+ json_value 
+------------
+ 123
+(1 row)
+
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+ERROR:  SQL/JSON item cannot be cast to target type
+SELECT JSON_VALUE(jsonb '1.23', '$');
+ json_value 
+------------
+ 1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+ json_value 
+------------
+       1.23
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "1.23"
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+ json_value 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+ json_value 
+------------
+ aaa  
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+ json_value 
+------------
+ aa
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+ json_value 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+ json_value 
+------------
+ "\"aaa\""
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+ json_value 
+------------
+           
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: "aaa"
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+ json_value 
+------------
+        111
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+ ?column? 
+----------
+      357
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+  ?column?  
+------------
+ 03-01-2017
+(1 row)
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+SELECT JSON_VALUE(jsonb '[]', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '{}', '$');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '1', '$.a');
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+ json_value 
+------------
+ error
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+ json_value 
+------------
+ 
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 2
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+ json_value 
+------------
+ 3
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+ json_value 
+------------
+ 0
+(1 row)
+
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+ERROR:  invalid input syntax for type integer: " "
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          5
+(1 row)
+
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+ json_value 
+------------
+          1
+(1 row)
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+ x | y  
+---+----
+ 0 | -2
+ 1 |  2
+ 2 | -1
+(3 rows)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+ json_value 
+------------
+ (1,2)
+(1 row)
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+          json_value          
+------------------------------
+ Tue Feb 20 18:34:56 2018 PST
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+        json_value        
+--------------------------
+ Tue Feb 20 18:34:56 2018
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_value          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- JSON_QUERY
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+     json_query     |     json_query     |     json_query     |      json_query      |      json_query      
+--------------------+--------------------+--------------------+----------------------+----------------------
+ null               | null               | [null]             | [null]               | [null]
+ 12.3               | 12.3               | [12.3]             | [12.3]               | [12.3]
+ true               | true               | [true]             | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]            | ["aaa"]              | ["aaa"]
+ [1, null, "2"]     | [1, null, "2"]     | [1, null, "2"]     | [[1, null, "2"]]     | [[1, null, "2"]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+(6 rows)
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+       unspec       |      without       |      with cond      |     with uncond      |         with         
+--------------------+--------------------+---------------------+----------------------+----------------------
+                    |                    |                     |                      | 
+                    |                    |                     |                      | 
+ null               | null               | [null]              | [null]               | [null]
+ 12.3               | 12.3               | [12.3]              | [12.3]               | [12.3]
+ true               | true               | [true]              | [true]               | [true]
+ "aaa"              | "aaa"              | ["aaa"]             | ["aaa"]              | ["aaa"]
+ [1, 2, 3]          | [1, 2, 3]          | [1, 2, 3]           | [[1, 2, 3]]          | [[1, 2, 3]]
+ {"a": 1, "b": [2]} | {"a": 1, "b": [2]} | {"a": 1, "b": [2]}  | [{"a": 1, "b": [2]}] | [{"a": 1, "b": [2]}]
+                    |                    | [1, "2", null, [3]] | [1, "2", null, [3]]  | [1, "2", null, [3]]
+(9 rows)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ "aaa"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+ json_query 
+------------
+ aaa
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+ERROR:  invalid input syntax for type json
+DETAIL:  Token "aaa" is invalid.
+CONTEXT:  JSON data, line 1: aaa
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+ json_query 
+------------
+ \x616161
+(1 row)
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES)...
+                                                        ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTE...
+                                                             ^
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+ERROR:  SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used
+LINE 1: ...N_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTE...
+                                                             ^
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+ json_query 
+------------
+ [1]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+ json_query 
+------------
+ []
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+ERROR:  no SQL/JSON item
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+ json_query 
+------------
+ 
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+ json_query 
+------------
+ "empty"
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+ json_query 
+------------
+ [1, 2]    
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+ json_query 
+------------
+ [1,
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+ json_query 
+------------
+ [1, 2]
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+   json_query   
+----------------
+ \x5b312c20325d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+ json_query 
+------------
+ {}
+(1 row)
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+ x | y |     list     
+---+---+--------------
+ 0 | 0 | []
+ 0 | 1 | [1]
+ 0 | 2 | [1, 2]
+ 0 | 3 | [1, 2, 3]
+ 0 | 4 | [1, 2, 3, 4]
+ 1 | 0 | []
+ 1 | 1 | [1]
+ 1 | 2 | [1, 2]
+ 1 | 3 | [1, 2, 3]
+ 1 | 4 | [1, 2, 3, 4]
+ 2 | 0 | []
+ 2 | 1 | []
+ 2 | 2 | [2]
+ 2 | 3 | [2, 3]
+ 2 | 4 | [2, 3, 4]
+ 3 | 0 | []
+ 3 | 1 | []
+ 3 | 2 | []
+ 3 | 3 | [3]
+ 3 | 4 | [3, 4]
+ 4 | 0 | []
+ 4 | 1 | []
+ 4 | 2 | []
+ 4 | 3 | []
+ 4 | 4 | [4]
+(25 rows)
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+                     json_query                      
+-----------------------------------------------------
+ (1,aaa,"[1, ""2"", {}]","{""x"": [1, ""2"", {}]}",)
+(1 row)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+         unnest         
+------------------------
+ {"a": 1, "b": ["foo"]}
+ {"a": 2, "c": {}}
+ 123
+(3 rows)
+
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+  json_query  
+--------------
+ {1,2,NULL,3}
+(1 row)
+
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+ a |      t      | js |     jb     | jsa 
+---+-------------+----+------------+-----
+ 1 | ["foo", []] |    |            | 
+ 2 |             |    | [{}, true] | 
+(2 rows)
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+ json_query 
+------------
+          1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+ERROR:  domain sqljsonb_int_not_null does not allow null values
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+         json_query          
+-----------------------------
+ "2018-02-21T02:34:56+00:00"
+(1 row)
+
+-- Test constraints
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+\d test_jsonb_constraints
+                                          Table "public.test_jsonb_constraints"
+ Column |  Type   | Collation | Nullable |                                    Default                                     
+--------+---------+-----------+----------+--------------------------------------------------------------------------------
+ js     | text    |           |          | 
+ i      | integer |           |          | 
+ x      | jsonb   |           |          | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+Check constraints:
+    "test_jsonb_constraint1" CHECK (js IS JSON)
+    "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr))
+    "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT ('12'::text || i)::integer ON EMPTY ERROR ON ERROR) > i)
+    "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb)
+    "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C"))
+    "test_jsonb_constraint6" CHECK (JSON_EXISTS(js::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2)
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+                                                       check_clause                                                       
+--------------------------------------------------------------------------------------------------------------------------
+ ((js IS JSON))
+ (JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr))
+ ((JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT (('12'::text || i))::integer ON EMPTY ERROR ON ERROR) > i))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < '[10]'::jsonb))
+ ((JSON_QUERY((js)::jsonb, '$."a"' RETURNING character(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")))
+ ((JSON_EXISTS((js)::jsonb, 'strict $."a"' RETURNING integer TRUE ON ERROR) < 2))
+(6 rows)
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+                                  pg_get_expr                                   
+--------------------------------------------------------------------------------
+ JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER)
+(1 row)
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint1"
+DETAIL:  Failing row contains (, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains (1, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ([], null, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint2"
+DETAIL:  Failing row contains ({"b": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint3"
+DETAIL:  Failing row contains ({"a": 1}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint5"
+DETAIL:  Failing row contains ({"a": 7}, 1, [1, 2]).
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+ERROR:  new row for relation "test_jsonb_constraints" violates check constraint "test_jsonb_constraint4"
+DETAIL:  Failing row contains ({"a": 10}, 1, [1, 2]).
+DROP TABLE test_jsonb_constraints;
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+ERROR:  functions in index expression must be marked IMMUTABLE
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/expected/opr_sanity.out b/src/test/regress/expected/opr_sanity.out
index 4ce6c039b4..15e4016836 100644
--- a/src/test/regress/expected/opr_sanity.out
+++ b/src/test/regress/expected/opr_sanity.out
@@ -1473,8 +1473,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
  aggfnoid | proname | oid | proname 
 ----------+---------+-----+---------
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
new file mode 100644
index 0000000000..6cadd87868
--- /dev/null
+++ b/src/test/regress/expected/sqljson.out
@@ -0,0 +1,1268 @@
+-- JSON()
+SELECT JSON();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON();
+                    ^
+SELECT JSON(NULL);
+ json 
+------
+ 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ');
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+                                   ^
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+     json     
+--------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT JSON('   1   '::json);
+  json   
+---------
+    1   
+(1 row)
+
+SELECT JSON('   1   '::jsonb);
+ json 
+------
+ 1
+(1 row)
+
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+ERROR:  cannot use non-string types with WITH UNIQUE KEYS clause
+LINE 1: SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+               ^
+SELECT JSON(123);
+ERROR:  cannot cast type integer to json
+LINE 1: SELECT JSON(123);
+                    ^
+SELECT JSON('{"a": 1, "a": 2}');
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+ERROR:  duplicate JSON object key value
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+       json       
+------------------
+ {"a": 1, "a": 2}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+                  QUERY PLAN                   
+-----------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+                         QUERY PLAN                          
+-------------------------------------------------------------
+ Result
+   Output: JSON('\x313233'::bytea FORMAT JSON ENCODING UTF8)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::text WITH UNIQUE KEYS)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+SELECT JSON('123' RETURNING text);
+ERROR:  cannot use RETURNING type text in JSON()
+LINE 1: SELECT JSON('123' RETURNING text);
+                                    ^
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+         QUERY PLAN          
+-----------------------------
+ Result
+   Output: JSON('123'::json)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+                  QUERY PLAN                  
+----------------------------------------------
+ Result
+   Output: JSON('123'::jsonb RETURNING jsonb)
+(2 rows)
+
+SELECT pg_typeof(JSON('123'));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING json));
+ pg_typeof 
+-----------
+ json
+(1 row)
+
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+ pg_typeof 
+-----------
+ jsonb
+(1 row)
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SCALAR();
+                           ^
+SELECT JSON_SCALAR(NULL);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(NULL::int);
+ json_scalar 
+-------------
+ 
+(1 row)
+
+SELECT JSON_SCALAR(123);
+ json_scalar 
+-------------
+ 123
+(1 row)
+
+SELECT JSON_SCALAR(123.45);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(123.45::numeric);
+ json_scalar 
+-------------
+ 123.45
+(1 row)
+
+SELECT JSON_SCALAR(true);
+ json_scalar 
+-------------
+ true
+(1 row)
+
+SELECT JSON_SCALAR(false);
+ json_scalar 
+-------------
+ false
+(1 row)
+
+SELECT JSON_SCALAR(' 123.45');
+ json_scalar 
+-------------
+ " 123.45"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07'::date);
+ json_scalar  
+--------------
+ "2020-06-07"
+(1 row)
+
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+      json_scalar      
+-----------------------
+ "2020-06-07T01:02:03"
+(1 row)
+
+SELECT JSON_SCALAR('{}'::json);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_SCALAR('{}'::jsonb);
+ json_scalar 
+-------------
+ {}
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+             QUERY PLAN             
+------------------------------------
+ Result
+   Output: JSON_SCALAR('123'::text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+         QUERY PLAN         
+----------------------------
+ Result
+   Output: JSON_SCALAR(123)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+                 QUERY PLAN                 
+--------------------------------------------
+ Result
+   Output: JSON_SCALAR(123 RETURNING jsonb)
+(2 rows)
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT JSON_SERIALIZE();
+                              ^
+SELECT JSON_SERIALIZE(NULL);
+ json_serialize 
+----------------
+ 
+(1 row)
+
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+ json_serialize 
+----------------
+ { "a" : 1 } 
+(1 row)
+
+SELECT JSON_SERIALIZE('1');
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+ json_serialize 
+----------------
+ 1
+(1 row)
+
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+       json_serialize       
+----------------------------
+ \x7b20226122203a2031207d20
+(1 row)
+
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+ pg_typeof 
+-----------
+ text
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+                     QUERY PLAN                      
+-----------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING text)
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+                      QUERY PLAN                      
+------------------------------------------------------
+ Result
+   Output: JSON_SERIALIZE('{}'::json RETURNING bytea)
+(2 rows)
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+ json_object 
+-------------
+ {}
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8)...
+                                          ^
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_OBJECT(RETURNING bytea);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_object 
+-------------
+ \x7b7d
+(1 row)
+
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF1...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF3...
+                                           ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+ERROR:  cannot use non-string types with explicit FORMAT JSON clause
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF...
+                                            ^
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+                                             ^
+  json_object   
+----------------
+ {"foo" : null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UT...
+                                             ^
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+WARNING:  FORMAT JSON has no effect for json and jsonb types
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+                                              ^
+  json_object  
+---------------
+ {"foo": null}
+(1 row)
+
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+ERROR:  JSON ENCODING clause is only allowed for bytea input type
+LINE 1: SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING U...
+                                              ^
+SELECT JSON_OBJECT(NULL: 1);
+ERROR:  argument 1 cannot be null
+HINT:  Object keys should be text.
+SELECT JSON_OBJECT('a': 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+ json_object 
+-------------
+ {"a" : 5}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+ json_object 
+-------------
+ {"a2" : 1}
+(1 row)
+
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+SELECT JSON_OBJECT('a' VALUE 2::text);
+ json_object 
+-------------
+ {"a" : "2"}
+(1 row)
+
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+SELECT JSON_OBJECT((1::text) VALUE 2);
+ json_object 
+-------------
+ {"1" : 2}
+(1 row)
+
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+ERROR:  key value must be scalar, not array, composite, or json
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+                            json_object                            
+-------------------------------------------------------------------
+ {"a": "123", "c": [1, true, {}], "d": {"x": 123.45}, "1.23": 123}
+(1 row)
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+                  json_object                  
+-----------------------------------------------
+ {"a" : "123", "b" : {"a" : 111, "b" : "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+                json_object                
+-------------------------------------------
+ {"a": "123", "b": {"a": 111, "b": "aaa"}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+      json_object      
+-----------------------
+ {"a" : "{\"b\" : 1}"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+           json_object           
+---------------------------------
+ {"a" : "\\x7b226222203a20317d"}
+(1 row)
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+    json_object    
+-------------------
+ {"a" : {"b" : 1}}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+           json_object            
+----------------------------------
+ {"a" : "1", "b" : null, "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+     json_object      
+----------------------
+ {"a" : "1", "c" : 2}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+    json_object     
+--------------------
+ {"1" : 1, "1" : 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+ json_object 
+-------------
+ {"1": 1}
+(1 row)
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+        json_object         
+----------------------------
+ {"1": 1, "3": 1, "5": "a"}
+(1 row)
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+ json_array 
+------------
+ []
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+ERROR:  cannot set JSON encoding for non-bytea output types
+LINE 1: SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+                                         ^
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+ERROR:  unrecognized JSON encoding: invalid_encoding
+SELECT JSON_ARRAY(RETURNING bytea);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+ json_array 
+------------
+ \x5b5d
+(1 row)
+
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+ERROR:  unsupported JSON encoding
+LINE 1: SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32...
+                                          ^
+HINT:  only UTF8 JSON encoding is supported
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+                     json_array                      
+-----------------------------------------------------
+ ["aaa", 111, true, [1, 2, 3], {"a": [1]}, ["a", 3]]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+    json_array    
+------------------
+ ["a", null, "b"]
+(1 row)
+
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["a", "b"]
+(1 row)
+
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+ json_array 
+------------
+ ["b"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+          json_array           
+-------------------------------
+ ["[\"{ \\\"a\\\" : 123 }\"]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+      json_array       
+-----------------------
+ ["[{ \"a\" : 123 }]"]
+(1 row)
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+    json_array     
+-------------------
+ [[{ "a" : 123 }]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+ json_array 
+------------
+ [1, 2, 4]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+ json_array 
+------------
+ [[1,2],   +
+  [3,4]]
+(1 row)
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+    json_array    
+------------------
+ [[1, 2], [3, 4]]
+(1 row)
+
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+ json_array 
+------------
+ [1, 2, 3]
+(1 row)
+
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+               ^
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+ERROR:  subquery must return only one column
+LINE 1: SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+               ^
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+  json_arrayagg  |  json_arrayagg  
+-----------------+-----------------
+ [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [5, 4, 3, 2, 1]
+(1 row)
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+  json_arrayagg  
+-----------------
+ [1, 2, 3, 4, 5]
+(1 row)
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+              json_arrayagg               
+------------------------------------------
+ [[1, 2], [2, 3], [3, 4], [4, 5], [5, 6]]
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+ json_arrayagg | json_arrayagg 
+---------------+---------------
+ []            | []
+(1 row)
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+         json_arrayagg          |         json_arrayagg          
+--------------------------------+--------------------------------
+ [null, null, null, null, null] | [null, null, null, null, null]
+(1 row)
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |  json_arrayagg  |              json_arrayagg              |              json_arrayagg              |  json_arrayagg  |                                                      json_arrayagg                                                       | json_arrayagg |            json_arrayagg             
+-----------------+-----------------+-----------------+-----------------+-----------------------------------------+-----------------------------------------+-----------------+--------------------------------------------------------------------------------------------------------------------------+---------------+--------------------------------------
+ [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [3, 1, 5, 2, 4] | [null, 3, 1, null, null, 5, 2, 4, null] | [null, 3, 1, null, null, 5, 2, 4, null] | [{"bar":null}, +| [{"bar": null}, {"bar": 3}, {"bar": 1}, {"bar": null}, {"bar": null}, {"bar": 5}, {"bar": 2}, {"bar": 4}, {"bar": null}] | [{"bar":3},  +| [{"bar": 3}, {"bar": 4}, {"bar": 5}]
+                 |                 |                 |                 |                                         |                                         |  {"bar":3},    +|                                                                                                                          |  {"bar":4},  +| 
+                 |                 |                 |                 |                                         |                                         |  {"bar":1},    +|                                                                                                                          |  {"bar":5}]   | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}, +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":5},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":2},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":4},    +|                                                                                                                          |               | 
+                 |                 |                 |                 |                                         |                                         |  {"bar":null}]  |                                                                                                                          |               | 
+(1 row)
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+ bar | json_arrayagg 
+-----+---------------
+   4 | [4, 4]
+   4 | [4, 4]
+   2 | [4, 4]
+   5 | [5, 3, 5]
+   3 | [5, 3, 5]
+   1 | [5, 3, 5]
+   5 | [5, 3, 5]
+     | 
+     | 
+     | 
+     | 
+(11 rows)
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+ ?column? | ?column? 
+----------+----------
+ t        | t
+(1 row)
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+ERROR:  field name must not be null
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+ERROR:  field name must not be null
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+                 json_objectagg                  |              json_objectagg              
+-------------------------------------------------+------------------------------------------
+ { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5}
+(1 row)
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+                json_objectagg                |                json_objectagg                |    json_objectagg    |         json_objectagg         |         json_objectagg         |  json_objectagg  
+----------------------------------------------+----------------------------------------------+----------------------+--------------------------------+--------------------------------+------------------
+ { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "1" : null, "2" : null, "3" : 3 } | { "1" : 1, "3" : 3 } | {"1": null, "2": null, "3": 3} | {"1": null, "2": null, "3": 3} | {"1": 1, "3": 3}
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON key "1"
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+    json_objectagg    
+----------------------
+ { "1" : 1, "2" : 2 }
+(1 row)
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+ERROR:  duplicate JSON object key value
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Result
+   Output: JSON_OBJECT('foo' : '1'::json, 'bar' : 'baz'::text RETURNING json)
+(2 rows)
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+\sv json_object_view
+CREATE OR REPLACE VIEW public.json_object_view AS
+ SELECT JSON_OBJECT('foo' : '1'::text FORMAT JSON, 'bar' : 'baz'::text RETURNING json) AS "json_object"
+DROP VIEW json_object_view;
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+                    QUERY PLAN                     
+---------------------------------------------------
+ Result
+   Output: JSON_ARRAY('1'::json, 2 RETURNING json)
+(2 rows)
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+\sv json_array_view
+CREATE OR REPLACE VIEW public.json_array_view AS
+ SELECT JSON_ARRAY('1'::text FORMAT JSON, 2 RETURNING json) AS "json_array"
+DROP VIEW json_array_view;
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                              QUERY PLAN                                                              
+--------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_OBJECTAGG(i : (('111'::text || (i)::text))::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_objectagg_view
+CREATE OR REPLACE VIEW public.json_objectagg_view AS
+ SELECT JSON_OBJECTAGG(i.i : ('111'::text || i.i)::bytea FORMAT JSON WITH UNIQUE KEYS RETURNING text) FILTER (WHERE i.i > 3) AS "json_objectagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_objectagg_view;
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+                                                         QUERY PLAN                                                          
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE (i > 3))
+   ->  Function Scan on pg_catalog.generate_series i
+         Output: i
+         Function Call: generate_series(1, 5)
+(5 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+                                                        QUERY PLAN                                                        
+--------------------------------------------------------------------------------------------------------------------------
+ WindowAgg
+   Output: JSON_ARRAYAGG((('111'::text || (i)::text))::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (?), ((i % 2))
+   ->  Sort
+         Output: ((i % 2)), i
+         Sort Key: ((i.i % 2))
+         ->  Function Scan on pg_catalog.generate_series i
+               Output: (i % 2), i
+               Function Call: generate_series(1, 5)
+(8 rows)
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+\sv json_arrayagg_view
+CREATE OR REPLACE VIEW public.json_arrayagg_view AS
+ SELECT JSON_ARRAYAGG(('111'::text || i.i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i.i > 3) AS "json_arrayagg"
+   FROM generate_series(1, 5) i(i)
+DROP VIEW json_arrayagg_view;
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+                             QUERY PLAN                              
+---------------------------------------------------------------------
+ Result
+   Output: $0
+   InitPlan 1 (returns $0)
+     ->  Aggregate
+           Output: JSON_ARRAYAGG("*VALUES*".column1 RETURNING jsonb)
+           ->  Values Scan on "*VALUES*"
+                 Output: "*VALUES*".column1
+(7 rows)
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+\sv json_array_subquery_view
+CREATE OR REPLACE VIEW public.json_array_subquery_view AS
+ SELECT ( SELECT JSON_ARRAYAGG(q.a RETURNING jsonb) AS "json_arrayagg"
+           FROM ( SELECT foo.i
+                   FROM ( VALUES (1), (2), (NULL::integer), (4)) foo(i)) q(a)) AS "json_array"
+DROP VIEW json_array_subquery_view;
+-- IS JSON predicate
+SELECT NULL IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL IS NOT JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::json IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::jsonb IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::text IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::bytea IS JSON;
+ ?column? 
+----------
+ 
+(1 row)
+
+SELECT NULL::int IS JSON;
+ERROR:  cannot use type integer in IS JSON predicate
+SELECT '' IS JSON;
+ ?column? 
+----------
+ f
+(1 row)
+
+SELECT bytea '\x00' IS JSON;
+ERROR:  invalid byte sequence for encoding "UTF8": 0x00
+CREATE TABLE test_is_json (js text);
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+                                               |         |             |          |           |          |           |                | 
+                                               | f       | t           | f        | f         | f        | f         | f              | f
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+ aaa                                           | f       | t           | f        | f         | f        | f         | f              | f
+ {a:1}                                         | f       | t           | f        | f         | f        | f         | f              | f
+ ["a",]                                        | f       | t           | f        | f         | f        | f         | f              | f
+(16 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+                      js                       | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+                      js0                      | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-----------------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                           | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                                        | t       | f           | t        | f         | f        | t         | t              | t
+ true                                          | t       | f           | t        | f         | f        | t         | t              | t
+ null                                          | t       | f           | t        | f         | f        | t         | t              | t
+ []                                            | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                                  | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                            | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": null }                         | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "a": null }                         | t       | f           | t        | t         | f        | f         | t              | f
+ { "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }     | t       | f           | t        | t         | f        | f         | t              | t
+ { "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] } | t       | f           | t        | t         | f        | f         | t              | f
+(11 rows)
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+                 js                  | IS JSON | IS NOT JSON | IS VALUE | IS OBJECT | IS ARRAY | IS SCALAR | WITHOUT UNIQUE | WITH UNIQUE 
+-------------------------------------+---------+-------------+----------+-----------+----------+-----------+----------------+-------------
+ 123                                 | t       | f           | t        | f         | f        | t         | t              | t
+ "aaa "                              | t       | f           | t        | f         | f        | t         | t              | t
+ true                                | t       | f           | t        | f         | f        | t         | t              | t
+ null                                | t       | f           | t        | f         | f        | t         | t              | t
+ []                                  | t       | f           | t        | f         | t        | f         | t              | t
+ [1, "2", {}]                        | t       | f           | t        | f         | t        | f         | t              | t
+ {}                                  | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": null}                 | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": null}                         | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 1}, {"a": 2}]} | t       | f           | t        | t         | f        | f         | t              | t
+ {"a": 1, "b": [{"a": 2, "b": 0}]}   | t       | f           | t        | t         | f        | f         | t              | t
+(11 rows)
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+                                                                        QUERY PLAN                                                                        
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Function Scan on pg_catalog.generate_series i
+   Output: ('1'::text IS JSON), (('1'::text || (i)::text) IS JSON SCALAR), (NOT ('[]'::text IS JSON ARRAY)), ('{}'::text IS JSON OBJECT WITH UNIQUE KEYS)
+   Function Call: generate_series(1, 3)
+(3 rows)
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+\sv is_json_view
+CREATE OR REPLACE VIEW public.is_json_view AS
+ SELECT '1'::text IS JSON AS "any",
+    ('1'::text || i.i) IS JSON SCALAR AS scalar,
+    NOT '[]'::text IS JSON ARRAY AS "array",
+    '{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
+   FROM generate_series(1, 3) i(i)
+DROP VIEW is_json_view;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 6d8f524ae9..b8cea3a5f2 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -111,7 +111,7 @@ test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combo
 # ----------
 # Another group of parallel tests (JSON related)
 # ----------
-test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath
+test: json jsonb json_encoding jsonpath jsonpath_encoding jsonb_jsonpath sqljson json_sqljson jsonb_sqljson
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
new file mode 100644
index 0000000000..4f30fa46b9
--- /dev/null
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -0,0 +1,11 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL FORMAT JSON, '$');
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL FORMAT JSON, '$');
+
+-- JSON_QUERY
+
+SELECT JSON_QUERY(NULL FORMAT JSON, '$');
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
new file mode 100644
index 0000000000..00a067a06a
--- /dev/null
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -0,0 +1,317 @@
+-- JSON_EXISTS
+
+SELECT JSON_EXISTS(NULL::jsonb, '$');
+
+SELECT JSON_EXISTS(jsonb '[]', '$');
+SELECT JSON_EXISTS(JSON_OBJECT(RETURNING jsonb), '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$');
+SELECT JSON_EXISTS(jsonb 'null', '$');
+SELECT JSON_EXISTS(jsonb '[]', '$');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_EXISTS(jsonb 'null', '$.a');
+SELECT JSON_EXISTS(jsonb '[]', '$.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'strict $.a');
+SELECT JSON_EXISTS(jsonb '[1, "aaa", {"a": 1}]', 'lax $.a');
+SELECT JSON_EXISTS(jsonb '{}', '$.a');
+SELECT JSON_EXISTS(jsonb '{"b": 1, "a": 2}', '$.a');
+
+SELECT JSON_EXISTS(jsonb '1', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": {"b": 1}}', '$.a.b');
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.a.b');
+
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING 1 AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x)' PASSING '1' AS x);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 2 AS y);
+SELECT JSON_EXISTS(jsonb '{"a": 1, "b": 2}', '$.* ? (@ > $x && @ < $y)' PASSING 0 AS x, 1 AS y);
+
+-- extension: boolean expressions
+SELECT JSON_EXISTS(jsonb '1', '$ > 2');
+SELECT JSON_EXISTS(jsonb '1', '$.a > 2' ERROR ON ERROR);
+
+-- extension: RETURNING clause
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING bool);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING int);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', '$[1]' RETURNING text);
+SELECT JSON_EXISTS(jsonb '1', 'strict $[1]' RETURNING text FALSE ON ERROR);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING jsonb);
+SELECT JSON_EXISTS(jsonb '1', '$[0]' RETURNING float4);
+
+
+-- JSON_VALUE
+
+SELECT JSON_VALUE(NULL::jsonb, '$');
+
+SELECT JSON_VALUE(jsonb 'null', '$');
+SELECT JSON_VALUE(jsonb 'null', '$' RETURNING int);
+
+SELECT JSON_VALUE(jsonb 'true', '$');
+SELECT JSON_VALUE(jsonb 'true', '$' RETURNING bool);
+
+SELECT JSON_VALUE(jsonb '123', '$');
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING int) + 234;
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING text);
+/* jsonb bytea ??? */
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING bytea ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1.23', '$');
+SELECT JSON_VALUE(jsonb '1.23', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING numeric);
+SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$');
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING json);
+SELECT JSON_VALUE(jsonb '"\"aaa\""', '$' RETURNING jsonb);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING int DEFAULT 111 ON ERROR);
+SELECT JSON_VALUE(jsonb '"123"', '$' RETURNING int) + 234;
+
+SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
+
+-- Test NULL checks execution in domain types
+CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null NULL ON ERROR);
+SELECT JSON_VALUE(jsonb '1', '$.a' RETURNING sqljsonb_int_not_null DEFAULT NULL ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[]', '$');
+SELECT JSON_VALUE(jsonb '[]', '$' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '{}', '$');
+SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
+
+SELECT JSON_VALUE(jsonb '1', '$.a');
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
+SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
+
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[1,2]', '$[*]' DEFAULT '0' ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '[" "]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+SELECT JSON_VALUE(jsonb '["1"]', '$[*]' RETURNING int DEFAULT 2 + 3 ON ERROR);
+
+SELECT
+	x,
+	JSON_VALUE(
+		jsonb '{"a": 1, "b": 2}',
+		'$.* ? (@ > $x)' PASSING x AS x
+		RETURNING int
+		DEFAULT -1 ON EMPTY
+		DEFAULT -2 ON ERROR
+	) y
+FROM
+	generate_series(0, 2) x;
+
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a);
+SELECT JSON_VALUE(jsonb 'null', '$a' PASSING point ' (1, 2 )' AS a RETURNING point);
+
+-- Test timestamptz passing and output
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamptz);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING timestamp);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_VALUE(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- JSON_QUERY
+
+SELECT
+	JSON_QUERY(js, '$'),
+	JSON_QUERY(js, '$' WITHOUT WRAPPER),
+	JSON_QUERY(js, '$' WITH CONDITIONAL WRAPPER),
+	JSON_QUERY(js, '$' WITH UNCONDITIONAL ARRAY WRAPPER),
+	JSON_QUERY(js, '$' WITH ARRAY WRAPPER)
+FROM
+	(VALUES
+		(jsonb 'null'),
+		('12.3'),
+		('true'),
+		('"aaa"'),
+		('[1, null, "2"]'),
+		('{"a": 1, "b": [2]}')
+	) foo(js);
+
+SELECT
+	JSON_QUERY(js, 'strict $[*]') AS "unspec",
+	JSON_QUERY(js, 'strict $[*]' WITHOUT WRAPPER) AS "without",
+	JSON_QUERY(js, 'strict $[*]' WITH CONDITIONAL WRAPPER) AS "with cond",
+	JSON_QUERY(js, 'strict $[*]' WITH UNCONDITIONAL ARRAY WRAPPER) AS "with uncond",
+	JSON_QUERY(js, 'strict $[*]' WITH ARRAY WRAPPER) AS "with"
+FROM
+	(VALUES
+		(jsonb '1'),
+		('[]'),
+		('[null]'),
+		('[12.3]'),
+		('[true]'),
+		('["aaa"]'),
+		('[[1, 2, 3]]'),
+		('[{"a": 1, "b": [2]}]'),
+		('[1, "2", null, [3]]')
+	) foo(js);
+
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text KEEP QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES ON SCALAR STRING);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
+
+-- QUOTES behavior should not be specified when WITH WRAPPER used:
+-- Should fail
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER KEEP QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITH CONDITIONAL WRAPPER OMIT QUOTES);
+-- Should succeed
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '[1]', '$' WITHOUT WRAPPER KEEP QUOTES);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]');
+SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY ARRAY ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' EMPTY OBJECT ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' DEFAULT '"empty"' ON EMPTY);
+
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING json FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
+SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
+
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
+SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
+
+SELECT
+	x, y,
+	JSON_QUERY(
+		jsonb '[1,2,3,4,5,null]',
+		'$[*] ? (@ >= $x && @ <= $y)'
+		PASSING x AS x, y AS y
+		WITH CONDITIONAL WRAPPER
+		EMPTY ARRAY ON EMPTY
+	) list
+FROM
+	generate_series(0, 4) x,
+	generate_series(0, 4) y;
+
+-- Extension: record types returning
+CREATE TYPE sqljsonb_rec AS (a int, t text, js json, jb jsonb, jsa json[]);
+CREATE TYPE sqljsonb_reca AS (reca sqljsonb_rec[]);
+
+SELECT JSON_QUERY(jsonb '[{"a": 1, "b": "foo", "t": "aaa", "js": [1, "2", {}], "jb": {"x": [1, "2", {}]}},  {"a": 2}]', '$[0]' RETURNING sqljsonb_rec);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"jsa":  [{"a": 1, "b": ["foo"]}, {"a": 2, "c": {}}, 123]}', '$' RETURNING sqljsonb_rec)).jsa);
+SELECT * FROM unnest((JSON_QUERY(jsonb '{"reca": [{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]}', '$' RETURNING sqljsonb_reca)).reca);
+
+-- Extension: array types returning
+SELECT JSON_QUERY(jsonb '[1,2,null,"3"]', '$[*]' RETURNING int[] WITH WRAPPER);
+SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb": [{}, true]}]', '$' RETURNING sqljsonb_rec[]));
+
+-- Extension: domain types returning
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
+SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
+
+-- Test timestamptz passing and output
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING json);
+SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts RETURNING jsonb);
+
+-- Test constraints
+
+CREATE TABLE test_jsonb_constraints (
+	js text,
+	i int,
+	x jsonb DEFAULT JSON_QUERY(jsonb '[1,2]', '$[*]' WITH WRAPPER)
+	CONSTRAINT test_jsonb_constraint1
+		CHECK (js IS JSON)
+	CONSTRAINT test_jsonb_constraint2
+		CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr))
+	CONSTRAINT test_jsonb_constraint3
+		CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT ('12' || i)::int ON EMPTY ERROR ON ERROR) > i)
+	CONSTRAINT test_jsonb_constraint4
+		CHECK (JSON_QUERY(js::jsonb, '$.a' WITH CONDITIONAL WRAPPER EMPTY OBJECT ON ERROR) < jsonb '[10]')
+	CONSTRAINT test_jsonb_constraint5
+		CHECK (JSON_QUERY(js::jsonb, '$.a' RETURNING char(5) OMIT QUOTES EMPTY ARRAY ON EMPTY) >  'a' COLLATE "C")
+	CONSTRAINT test_jsonb_constraint6
+		CHECK (JSON_EXISTS(js::jsonb, 'strict $.a' RETURNING int TRUE ON ERROR) < 2)
+);
+
+\d test_jsonb_constraints
+
+SELECT check_clause
+FROM information_schema.check_constraints
+WHERE constraint_name LIKE 'test_jsonb_constraint%';
+
+SELECT pg_get_expr(adbin, adrelid) FROM pg_attrdef WHERE adrelid = 'test_jsonb_constraints'::regclass;
+
+INSERT INTO test_jsonb_constraints VALUES ('', 1);
+INSERT INTO test_jsonb_constraints VALUES ('1', 1);
+INSERT INTO test_jsonb_constraints VALUES ('[]');
+INSERT INTO test_jsonb_constraints VALUES ('{"b": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 1}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 7}', 1);
+INSERT INTO test_jsonb_constraints VALUES ('{"a": 10}', 1);
+
+DROP TABLE test_jsonb_constraints;
+
+-- Test mutabilily od query functions
+CREATE TABLE test_jsonb_mutability(js jsonb);
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a[0]'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime()'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@ < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime())'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime() < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("HH:MI TZH"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.a ? (@.datetime("HH:MI TZH") < $.datetime("YY-MM-DD HH:MI"))'));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("HH:MI TZH") < $y' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '12:34'::timetz AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() < $x' PASSING '1234'::int AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime() ? (@ == $x)' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$.datetime("YY-MM-DD") ? (@ == $x)' PASSING '2020-07-14'::date AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
+CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
+DROP TABLE test_jsonb_mutability;
diff --git a/src/test/regress/sql/opr_sanity.sql b/src/test/regress/sql/opr_sanity.sql
index 2b292851e3..63fe114fed 100644
--- a/src/test/regress/sql/opr_sanity.sql
+++ b/src/test/regress/sql/opr_sanity.sql
@@ -854,8 +854,10 @@ WHERE a.aggfnoid = p.oid AND
          NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
      OR (p.pronargs > 2 AND
          NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-     -- we could carry the check further, but 3 args is enough for now
-     OR (p.pronargs > 3)
+     OR (p.pronargs > 3 AND
+         NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
+     -- we could carry the check further, but 4 args is enough for now
+     OR (p.pronargs > 4)
     );
 
 -- Cross-check finalfn (if present) against its entry in pg_proc.
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
new file mode 100644
index 0000000000..51fc659b58
--- /dev/null
+++ b/src/test/regress/sql/sqljson.sql
@@ -0,0 +1,445 @@
+-- JSON()
+SELECT JSON();
+SELECT JSON(NULL);
+SELECT JSON('{ "a" : 1 } ');
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
+SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
+SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
+SELECT pg_typeof(JSON('{ "a" : 1 } '));
+
+SELECT JSON('   1   '::json);
+SELECT JSON('   1   '::jsonb);
+SELECT JSON('   1   '::json WITH UNIQUE KEYS);
+SELECT JSON(123);
+
+SELECT JSON('{"a": 1, "a": 2}');
+SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
+SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
+
+SELECT JSON('123' RETURNING text);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' RETURNING jsonb);
+SELECT pg_typeof(JSON('123'));
+SELECT pg_typeof(JSON('123' RETURNING json));
+SELECT pg_typeof(JSON('123' RETURNING jsonb));
+
+-- JSON_SCALAR()
+SELECT JSON_SCALAR();
+SELECT JSON_SCALAR(NULL);
+SELECT JSON_SCALAR(NULL::int);
+SELECT JSON_SCALAR(123);
+SELECT JSON_SCALAR(123.45);
+SELECT JSON_SCALAR(123.45::numeric);
+SELECT JSON_SCALAR(true);
+SELECT JSON_SCALAR(false);
+SELECT JSON_SCALAR(' 123.45');
+SELECT JSON_SCALAR('2020-06-07'::date);
+SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
+SELECT JSON_SCALAR('{}'::json);
+SELECT JSON_SCALAR('{}'::jsonb);
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING json);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123 RETURNING jsonb);
+
+-- JSON_SERIALIZE()
+SELECT JSON_SERIALIZE();
+SELECT JSON_SERIALIZE(NULL);
+SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
+SELECT JSON_SERIALIZE('{ "a" : 1 } ');
+SELECT JSON_SERIALIZE('1');
+SELECT JSON_SERIALIZE('1' FORMAT JSON);
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
+SELECT pg_typeof(JSON_SERIALIZE(NULL));
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
+EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
+
+-- JSON_OBJECT()
+SELECT JSON_OBJECT();
+SELECT JSON_OBJECT(RETURNING json);
+SELECT JSON_OBJECT(RETURNING json FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING jsonb);
+SELECT JSON_OBJECT(RETURNING jsonb FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_OBJECT(RETURNING bytea);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_OBJECT(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::int FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::json FORMAT JSON ENCODING UTF8);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON);
+SELECT JSON_OBJECT('foo': NULL::jsonb FORMAT JSON ENCODING UTF8);
+
+SELECT JSON_OBJECT(NULL: 1);
+SELECT JSON_OBJECT('a': 2 + 3);
+SELECT JSON_OBJECT('a' VALUE 2 + 3);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2 + 3);
+SELECT JSON_OBJECT('a' || 2: 1);
+SELECT JSON_OBJECT(('a' || 2) VALUE 1);
+--SELECT JSON_OBJECT('a' || 2 VALUE 1);
+--SELECT JSON_OBJECT(KEY 'a' || 2 VALUE 1);
+SELECT JSON_OBJECT('a': 2::text);
+SELECT JSON_OBJECT('a' VALUE 2::text);
+--SELECT JSON_OBJECT(KEY 'a' VALUE 2::text);
+SELECT JSON_OBJECT(1::text: 2);
+SELECT JSON_OBJECT((1::text) VALUE 2);
+--SELECT JSON_OBJECT(1::text VALUE 2);
+--SELECT JSON_OBJECT(KEY 1::text VALUE 2);
+SELECT JSON_OBJECT(json '[1]': 123);
+SELECT JSON_OBJECT(ARRAY[1,2,3]: 'aaa');
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+);
+
+SELECT JSON_OBJECT(
+	'a': '123',
+	1.23: 123,
+	'c': json '[ 1,true,{ } ]',
+	'd': jsonb '{ "x" : 123.45 }'
+	RETURNING jsonb
+);
+
+/*
+SELECT JSON_OBJECT(
+	'a': '123',
+	KEY 1.23 VALUE 123,
+	'c' VALUE json '[1, true, {}]'
+);
+*/
+
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa'));
+SELECT JSON_OBJECT('a': '123', 'b': JSON_OBJECT('a': 111, 'b': 'aaa' RETURNING jsonb));
+
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING text) FORMAT JSON);
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING bytea) FORMAT JSON);
+
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 NULL ON NULL);
+SELECT JSON_OBJECT('a': '1', 'b': NULL, 'c': 2 ABSENT ON NULL);
+
+SELECT JSON_OBJECT(1: 1, '1': NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '1': NULL NULL ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '1': NULL ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 NULL ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '1': 1 ABSENT ON NULL WITHOUT UNIQUE RETURNING jsonb);
+SELECT JSON_OBJECT(1: 1, '2': NULL, '3': 1, 4: NULL, '5': 'a' ABSENT ON NULL WITH UNIQUE RETURNING jsonb);
+
+
+-- JSON_ARRAY()
+SELECT JSON_ARRAY();
+SELECT JSON_ARRAY(RETURNING json);
+SELECT JSON_ARRAY(RETURNING json FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING jsonb);
+SELECT JSON_ARRAY(RETURNING jsonb FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING text FORMAT JSON ENCODING INVALID_ENCODING);
+SELECT JSON_ARRAY(RETURNING bytea);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF8);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF16);
+SELECT JSON_ARRAY(RETURNING bytea FORMAT JSON ENCODING UTF32);
+
+SELECT JSON_ARRAY('aaa', 111, true, array[1,2,3], NULL, json '{"a": [1]}', jsonb '["a",3]');
+
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL);
+SELECT JSON_ARRAY('a',  NULL, 'b' NULL   ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY('a',  NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(NULL, NULL, 'b' ABSENT ON NULL RETURNING jsonb);
+
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' FORMAT JSON RETURNING text) FORMAT JSON);
+
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i));
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) RETURNING jsonb);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL);
+--SELECT JSON_ARRAY(SELECT i FROM (VALUES (NULL::int[]), ('{1,2}'), (NULL), (NULL), ('{3,4}'), (NULL)) foo(i) NULL ON NULL RETURNING jsonb);
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (3), (1), (NULL), (2)) foo(i) ORDER BY i);
+-- Should fail
+SELECT JSON_ARRAY(SELECT FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT i, i FROM (VALUES (1)) foo(i));
+SELECT JSON_ARRAY(SELECT * FROM (VALUES (1, 2)) foo(i, j));
+
+-- JSON_ARRAYAGG()
+SELECT	JSON_ARRAYAGG(i) IS NULL,
+		JSON_ARRAYAGG(i RETURNING jsonb) IS NULL
+FROM generate_series(1, 0) i;
+
+SELECT	JSON_ARRAYAGG(i),
+		JSON_ARRAYAGG(i RETURNING jsonb)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i ORDER BY i DESC)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(i::text::json)
+FROM generate_series(1, 5) i;
+
+SELECT JSON_ARRAYAGG(JSON_ARRAY(i, i + 1 RETURNING text) FORMAT JSON)
+FROM generate_series(1, 5) i;
+
+SELECT	JSON_ARRAYAGG(NULL),
+		JSON_ARRAYAGG(NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT	JSON_ARRAYAGG(NULL NULL ON NULL),
+		JSON_ARRAYAGG(NULL NULL ON NULL RETURNING jsonb)
+FROM generate_series(1, 5);
+
+SELECT
+	JSON_ARRAYAGG(bar),
+	JSON_ARRAYAGG(bar RETURNING jsonb),
+	JSON_ARRAYAGG(bar ABSENT ON NULL),
+	JSON_ARRAYAGG(bar ABSENT ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(bar NULL ON NULL),
+	JSON_ARRAYAGG(bar NULL ON NULL RETURNING jsonb),
+	JSON_ARRAYAGG(foo),
+	JSON_ARRAYAGG(foo RETURNING jsonb),
+	JSON_ARRAYAGG(foo ORDER BY bar) FILTER (WHERE bar > 2),
+	JSON_ARRAYAGG(foo ORDER BY bar RETURNING jsonb) FILTER (WHERE bar > 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL)) foo(bar);
+
+SELECT
+	bar, JSON_ARRAYAGG(bar) FILTER (WHERE bar > 2) OVER (PARTITION BY foo.bar % 2)
+FROM
+	(VALUES (NULL), (3), (1), (NULL), (NULL), (5), (2), (4), (NULL), (5), (4)) foo(bar);
+
+-- JSON_OBJECTAGG()
+SELECT	JSON_OBJECTAGG('key': 1) IS NULL,
+		JSON_OBJECTAGG('key': 1 RETURNING jsonb) IS NULL
+WHERE FALSE;
+
+SELECT JSON_OBJECTAGG(NULL: 1);
+
+SELECT JSON_OBJECTAGG(NULL: 1 RETURNING jsonb);
+
+SELECT
+	JSON_OBJECTAGG(i: i),
+--	JSON_OBJECTAGG(i VALUE i),
+--	JSON_OBJECTAGG(KEY i VALUE i),
+	JSON_OBJECTAGG(i: i RETURNING jsonb)
+FROM
+	generate_series(1, 5) i;
+
+SELECT
+	JSON_OBJECTAGG(k: v),
+	JSON_OBJECTAGG(k: v NULL ON NULL),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL),
+	JSON_OBJECTAGG(k: v RETURNING jsonb),
+	JSON_OBJECTAGG(k: v NULL ON NULL RETURNING jsonb),
+	JSON_OBJECTAGG(k: v ABSENT ON NULL RETURNING jsonb)
+FROM
+	(VALUES (1, 1), (1, NULL), (2, NULL), (3, 3)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS)
+FROM (VALUES (1, 1), (0, NULL), (3, NULL), (2, 2), (4, NULL)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
+FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
+
+-- Test JSON_OBJECT deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+CREATE VIEW json_object_view AS
+SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
+
+\sv json_object_view
+
+DROP VIEW json_object_view;
+
+-- Test JSON_ARRAY deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+CREATE VIEW json_array_view AS
+SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);
+
+\sv json_array_view
+
+DROP VIEW json_array_view;
+
+-- Test JSON_OBJECTAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_objectagg_view AS
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_objectagg_view
+
+DROP VIEW json_objectagg_view;
+
+-- Test JSON_ARRAYAGG deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) OVER (PARTITION BY i % 2)
+FROM generate_series(1,5) i;
+
+CREATE VIEW json_arrayagg_view AS
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING text) FILTER (WHERE i > 3)
+FROM generate_series(1,5) i;
+
+\sv json_arrayagg_view
+
+DROP VIEW json_arrayagg_view;
+
+-- Test JSON_ARRAY(subquery) deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+CREATE VIEW json_array_subquery_view AS
+SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING jsonb);
+
+\sv json_array_subquery_view
+
+DROP VIEW json_array_subquery_view;
+
+-- IS JSON predicate
+SELECT NULL IS JSON;
+SELECT NULL IS NOT JSON;
+SELECT NULL::json IS JSON;
+SELECT NULL::jsonb IS JSON;
+SELECT NULL::text IS JSON;
+SELECT NULL::bytea IS JSON;
+SELECT NULL::int IS JSON;
+
+SELECT '' IS JSON;
+
+SELECT bytea '\x00' IS JSON;
+
+CREATE TABLE test_is_json (js text);
+
+INSERT INTO test_is_json VALUES
+ (NULL),
+ (''),
+ ('123'),
+ ('"aaa "'),
+ ('true'),
+ ('null'),
+ ('[]'),
+ ('[1, "2", {}]'),
+ ('{}'),
+ ('{ "a": 1, "b": null }'),
+ ('{ "a": 1, "a": null }'),
+ ('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
+ ('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
+ ('aaa'),
+ ('{a:1}'),
+ ('["a",]');
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	test_is_json;
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
+
+SELECT
+	js0,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
+
+SELECT
+	js,
+	js IS JSON "IS JSON",
+	js IS NOT JSON "IS NOT JSON",
+	js IS JSON VALUE "IS VALUE",
+	js IS JSON OBJECT "IS OBJECT",
+	js IS JSON ARRAY "IS ARRAY",
+	js IS JSON SCALAR "IS SCALAR",
+	js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
+	js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
+FROM
+	(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
+
+-- Test IS JSON deparsing
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+CREATE VIEW is_json_view AS
+SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
+
+\sv is_json_view
+
+DROP VIEW is_json_view;
-- 
2.25.1

0002-JSON_TABLE-v59.patchtext/x-patch; charset=UTF-8; name=0002-JSON_TABLE-v59.patchDownload
From 3ab859d900cc63c2b3f8fed8a297f8f6ccb577e7 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:01:20 -0500
Subject: [PATCH 2/4] JSON_TABLE

---
 doc/src/sgml/func.sgml                      | 330 ++++++++++++
 src/backend/commands/explain.c              |   8 +-
 src/backend/executor/execExpr.c             |   1 +
 src/backend/executor/execExprInterp.c       |  18 +-
 src/backend/executor/nodeTableFuncscan.c    |  23 +-
 src/backend/nodes/copyfuncs.c               |  85 +++
 src/backend/nodes/equalfuncs.c              |  65 +++
 src/backend/nodes/nodeFuncs.c               |  27 +
 src/backend/nodes/outfuncs.c                |  29 +
 src/backend/nodes/readfuncs.c               |  31 ++
 src/backend/parser/Makefile                 |   1 +
 src/backend/parser/gram.y                   | 199 ++++++-
 src/backend/parser/parse_clause.c           |  12 +-
 src/backend/parser/parse_expr.c             |  24 +-
 src/backend/parser/parse_jsontable.c        | 466 ++++++++++++++++
 src/backend/parser/parse_relation.c         |   3 +-
 src/backend/parser/parse_target.c           |   3 +
 src/backend/utils/adt/jsonpath_exec.c       | 436 +++++++++++++++
 src/backend/utils/adt/ruleutils.c           | 228 +++++++-
 src/backend/utils/misc/queryjumble.c        |   2 +
 src/include/executor/execExpr.h             |   4 +
 src/include/nodes/nodes.h                   |   4 +
 src/include/nodes/parsenodes.h              |  48 ++
 src/include/nodes/primnodes.h               |  39 +-
 src/include/parser/kwlist.h                 |   3 +
 src/include/parser/parse_clause.h           |   3 +
 src/include/utils/jsonpath.h                |   4 +
 src/test/regress/expected/json_sqljson.out  |   6 +
 src/test/regress/expected/jsonb_sqljson.out | 562 ++++++++++++++++++++
 src/test/regress/sql/json_sqljson.sql       |   4 +
 src/test/regress/sql/jsonb_sqljson.sql      | 284 ++++++++++
 src/tools/pgindent/typedefs.list            |   9 +
 32 files changed, 2928 insertions(+), 33 deletions(-)
 create mode 100644 src/backend/parser/parse_jsontable.c

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 891d237de1..a256f8123f 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18632,6 +18632,11 @@ FROM films AS f;
        <link linkend="functions-jsonquery"><literal>JSON_QUERY</literal></link>
       </para>
     </listitem>
+    <listitem>
+      <para>
+       <link linkend="functions-jsontable"><literal>JSON_TABLE</literal></link>
+      </para>
+    </listitem>
   </itemizedlist>
 
   <para>
@@ -19302,6 +19307,331 @@ FROM
     </sect5>
    </sect4>
 
+   <sect4 id="functions-jsontable">
+    <title><literal>JSON_TABLE</literal></title>
+    <indexterm><primary>json_table</primary></indexterm>
+
+<synopsis>
+JSON_TABLE (
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+)
+<phrase>
+where <replaceable class="parameter">json_table_column</replaceable> is:
+</phrase>
+    <replaceable>name</replaceable> <replaceable>type</replaceable> <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+        <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
+        <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
+        <optional> { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
+  | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+        <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
+  | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
+        COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
+  | <replaceable>name</replaceable> FOR ORDINALITY
+
+</synopsis>
+
+    <sect5>
+     <title>Description</title>
+
+     <para>
+      <function>JSON_TABLE</function> function queries <acronym>JSON</acronym> data
+      and presents the results as a relational view, which can be accessed as a
+      regular SQL table. You can only use <function>JSON_TABLE</function> inside the
+      <literal>FROM</literal> clause of the <literal>SELECT</literal> statement
+      for an SQL table.
+     </para>
+
+     <para>
+      Taking JSON data as input, <function>JSON_TABLE</function> uses
+      a path expression to extract a part of the provided data that
+      will be used as a <firstterm>row pattern</firstterm> for the
+      constructed view. Each SQL/JSON item at the top level of the row pattern serves
+      as the source for a separate row in the constructed relational view.
+     </para>
+
+    <para>
+      To split the row pattern into columns, <function>JSON_TABLE</function>
+      provides the <literal>COLUMNS</literal> clause that defines the
+      schema of the created view. For each column to be constructed,
+      this clause provides a separate path expression that evaluates
+      the row pattern, extracts a JSON item, and returns it as a
+      separate SQL value for the specified column. If the required value
+      is stored in a nested level of the row pattern, it can be extracted
+      using the <literal>NESTED PATH</literal> subclause. Joining the
+      columns returned by <literal>NESTED PATH</literal> can add multiple
+      new rows to the constructed view. Such rows are called
+      <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
+      that generates them.
+     </para>
+
+     <para>
+      The rows produced by <function>JSON_TABLE</function> are laterally
+      joined to the row that generated them, so you do not have to explicitly join
+      the constructed view with the original table holding <acronym>JSON</acronym>
+      data.
+     </para>
+
+     <para>
+      Each <literal>NESTED PATH</literal> clause can generate one or more
+      columns, which are considered to be <firstterm>siblings</firstterm>
+      to each other. In relation to the columns returned directly from the row
+      expression or by the <literal>NESTED PATH</literal> clause of a
+      higher level, these columns are <firstterm>child</firstterm> columns.
+      Sibling columns are always joined first. Once they are processed,
+      the resulting rows are joined to the parent row.
+     </para>
+
+     <para>
+      Columns with parent/child relationship are joined using
+      <literal>LEFT OUTER JOIN</literal>, so that the parent row
+      is always included into the output even if it does not have any child rows
+      after joining the data returned by <literal>NESTED PATH</literal>,
+      with NULL values inserted into the child columns if the corresponding
+      values are missing.
+     </para>
+
+     <para>
+      Sibling columns are joined using
+      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+      rows are included into the output, with NULL values inserted
+      into both child and parent columns for all missing values.
+     </para>
+
+    </sect5>
+    <sect5>
+     <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     The input data to query, the JSON path expression defining the query,
+     and an optional <literal>PASSING</literal> clause, as described in
+     <xref linkend="sqljson-input-clause"/>. The result of the input data
+     evaluation is called the <firstterm>row pattern</firstterm>. The row
+     pattern is used as the source for row values in the constructed view.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>COLUMNS( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     The <literal>COLUMNS</literal> clause defining the schema of the
+     constructed view. In this clause, you must specify all the columns
+     to be filled with SQL/JSON items.
+     The <replaceable class="parameter">json_table_column</replaceable>
+     expression has the following syntax variants:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Inserts a single SQL/JSON item into each row of
+     the specified column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonvalue"/> and
+      <xref linkend="functions-jsonquery"/> are used to produce resulting values.
+      <xref linkend="functions-jsonquery"/> is used for JSON, array, and
+      composite column types, <xref linkend="functions-jsonvalue"/> is used for
+      other types.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON EMPTY</literal> and
+     <literal>ON ERROR</literal> clauses to define how to handle missing values
+     or structural errors.
+     <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
+     be used with JSON, array, and composite types.
+     These clauses have the same syntax and semantics as in
+     <xref linkend="functions-jsonvalue"/> and
+     <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> <replaceable>type</replaceable> FORMAT <replaceable>json_representation</replaceable>
+          <optional> PATH <replaceable>json_path_specification</replaceable> </optional></literal>
+    </term>
+    <listitem>
+
+    <para>
+     Generates a column and inserts a composite SQL/JSON
+     item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>
+     and fills the column with produced SQL/JSON items, one for each row.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+     In this case, the column name must correspond to one of the
+     keys within the SQL/JSON item produced by the row pattern.
+    </para>
+    <para>
+      Internally, <xref linkend="functions-jsonquery"/> is used to produce
+      resulting values.
+    </para>
+    <para>
+     Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
+     <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
+     to define additional settings for the returned SQL/JSON items.
+     These clauses have the same syntax and semantics as
+     in <xref linkend="functions-jsonquery"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>
+       <replaceable>name</replaceable> <replaceable>type</replaceable>
+       EXISTS <optional> PATH <replaceable>json_path_specification</replaceable> </optional>
+     </literal>
+    </term>
+    <listitem>
+
+    <para>
+     Generates a column and inserts a boolean item into each row of this column.
+    </para>
+    <para>
+     The provided <literal>PATH</literal> expression parses the
+     row pattern defined by <replaceable>json_api_common_syntax</replaceable>,
+     checks whether any SQL/JSON items were returned, and fills the column with
+     resulting boolean value, one for each row.
+     The specified <replaceable>type</replaceable> should have cast from
+     <type>boolean</type>.
+     If the <literal>PATH</literal> expression is omitted,
+     <function>JSON_TABLE</function> uses the
+     <literal>$.<replaceable>name</replaceable></literal> path expression,
+     where <replaceable>name</replaceable> is the provided column name.
+    </para>
+    <para>
+     Optionally, you can add <literal>ON ERROR</literal> clause to define
+     error behavior.  This clause have the same syntax and semantics as in
+     <xref linkend="functions-jsonexists"/>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional>
+          COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Extracts SQL/JSON items from nested levels of the row pattern,
+     generates one or more columns as defined by the <literal>COLUMNS</literal>
+     subclause, and inserts the extracted SQL/JSON items into each row of these columns.
+     The <replaceable>json_table_column</replaceable> expression in the
+     <literal>COLUMNS</literal> subclause uses the same syntax as in the
+     parent <literal>COLUMNS</literal> clause.
+    </para>
+
+    <para>
+     The <literal>NESTED PATH</literal> syntax is recursive,
+     so you can go down multiple nested levels by specifying several
+     <literal>NESTED PATH</literal> subclauses within each other.
+     It allows to unnest the hierarchy of JSON objects and arrays
+     in a single function invocation rather than chaining several
+     <function>JSON_TABLE</function> expressions in an SQL statement.
+    </para>
+
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal><replaceable>name</replaceable> FOR ORDINALITY</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Adds an ordinality column that provides sequential row numbering.
+     You can have only one ordinality column per table. Row numbering
+     is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
+     clauses, the parent row number is repeated.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+    </listitem>
+   </varlistentry>
+
+  </variablelist>
+
+    </sect5>
+
+    <sect5>
+     <title>Examples</title>
+
+     <para>
+      Query the <structname>my_films</structname> table holding
+      some JSON data about the films and create a view that
+      distributes the film genre, title, and director between separate columns:
+<screen>
+SELECT jt.* FROM 
+ my_films,
+ JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
+   id FOR ORDINALITY,
+   kind text PATH '$.kind',
+   NESTED PATH '$.films[*]' COLUMNS (
+     title text PATH '$.title',
+     director text PATH '$.director'))) AS jt;
+----+----------+------------------+-------------------
+ id |   kind   |       title      |    director
+----+----------+------------------+-------------------
+ 1  | comedy   | Bananas          | Woody Allen
+ 1  | comedy   | The Dinner Game  | Francis Veber
+ 2  | horror   | Psycho           | Alfred Hitchcock
+ 3  | thriller | Vertigo          | Hitchcock
+ 4  | drama    | Yojimbo          | Akira Kurosawa
+ (5 rows)
+</screen>
+     </para>
+
+   </sect5>
+  </sect4>
 
   </sect3>
 
diff --git a/src/backend/commands/explain.c b/src/backend/commands/explain.c
index 9f632285b6..853f89afe4 100644
--- a/src/backend/commands/explain.c
+++ b/src/backend/commands/explain.c
@@ -3793,7 +3793,13 @@ ExplainTargetRel(Plan *plan, Index rti, ExplainState *es)
 			break;
 		case T_TableFuncScan:
 			Assert(rte->rtekind == RTE_TABLEFUNC);
-			objectname = "xmltable";
+			if (rte->tablefunc)
+				if (rte->tablefunc->functype == TFT_XMLTABLE)
+					objectname = "xmltable";
+				else /* Must be TFT_JSON_TABLE */
+					objectname = "json_table";
+			else
+				objectname = NULL;
 			objecttag = "Table Function Name";
 			break;
 		case T_ValuesScan:
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index d4d3850ec7..38b94c0276 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -2635,6 +2635,7 @@ ExecInitExprRec(Expr *node, ExprState *state,
 					var->typmod = exprTypmod((Node *) argexpr);
 					var->estate = ExecInitExpr(argexpr, state->parent);
 					var->econtext = NULL;
+					var->mcxt = NULL;
 					var->evaluated = false;
 					var->value = (Datum) 0;
 					var->isnull = true;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0d005dac13..309f95ab93 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4602,6 +4602,7 @@ ExecEvalJsonBehavior(ExprContext *econtext, JsonBehavior *behavior,
 
 		case JSON_BEHAVIOR_NULL:
 		case JSON_BEHAVIOR_UNKNOWN:
+		case JSON_BEHAVIOR_EMPTY:
 			*is_null = true;
 			return (Datum) 0;
 
@@ -4694,8 +4695,14 @@ EvalJsonPathVar(void *cxt, char *varName, int varNameLen,
 
 	if (!var->evaluated)
 	{
+		MemoryContext oldcxt = var->mcxt ?
+			MemoryContextSwitchTo(var->mcxt) : NULL;
+
 		var->value = ExecEvalExpr(var->estate, var->econtext, &var->isnull);
 		var->evaluated = true;
+
+		if (oldcxt)
+			MemoryContextSwitchTo(oldcxt);
 	}
 
 	if (var->isnull)
@@ -4843,6 +4850,7 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 	PG_CATCH();
 	{
 		ErrorData  *edata;
+		int			ecategory;
 
 		/* Save error info in oldcontext */
 		MemoryContextSwitchTo(oldcontext);
@@ -4854,8 +4862,10 @@ ExecEvalJsonExprSubtrans(JsonFunc func, ExprEvalStep *op,
 		MemoryContextSwitchTo(oldcontext);
 		CurrentResourceOwner = oldowner;
 
-		if (ERRCODE_TO_CATEGORY(edata->sqlerrcode) !=
-			ERRCODE_DATA_EXCEPTION)
+		ecategory = ERRCODE_TO_CATEGORY(edata->sqlerrcode);
+
+		if (ecategory != ERRCODE_DATA_EXCEPTION &&	/* jsonpath and other data errors */
+			ecategory != ERRCODE_INTEGRITY_CONSTRAINT_VIOLATION)	/* domain errors */
 			ReThrowError(edata);
 
 		res = (Datum) 0;
@@ -4981,6 +4991,10 @@ ExecEvalJsonExpr(ExprEvalStep *op, ExprContext *econtext,
 				break;
 			}
 
+		case IS_JSON_TABLE:
+			*resnull = false;
+			return item;
+
 		default:
 			elog(ERROR, "unrecognized SQL/JSON expression op %d", jexpr->op);
 			return (Datum) 0;
diff --git a/src/backend/executor/nodeTableFuncscan.c b/src/backend/executor/nodeTableFuncscan.c
index 0db4ed0c2f..691c3e28ce 100644
--- a/src/backend/executor/nodeTableFuncscan.c
+++ b/src/backend/executor/nodeTableFuncscan.c
@@ -28,6 +28,7 @@
 #include "miscadmin.h"
 #include "nodes/execnodes.h"
 #include "utils/builtins.h"
+#include "utils/jsonpath.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/xml.h"
@@ -161,8 +162,9 @@ ExecInitTableFuncScan(TableFuncScan *node, EState *estate, int eflags)
 	scanstate->ss.ps.qual =
 		ExecInitQual(node->scan.plan.qual, &scanstate->ss.ps);
 
-	/* Only XMLTABLE is supported currently */
-	scanstate->routine = &XmlTableRoutine;
+	/* Only XMLTABLE and JSON_TABLE are supported currently */
+	scanstate->routine =
+		tf->functype == TFT_XMLTABLE ? &XmlTableRoutine : &JsonbTableRoutine;
 
 	scanstate->perTableCxt =
 		AllocSetContextCreate(CurrentMemoryContext,
@@ -381,14 +383,17 @@ tfuncInitialize(TableFuncScanState *tstate, ExprContext *econtext, Datum doc)
 		routine->SetNamespace(tstate, ns_name, ns_uri);
 	}
 
-	/* Install the row filter expression into the table builder context */
-	value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
-	if (isnull)
-		ereport(ERROR,
-				(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
-				 errmsg("row filter expression must not be null")));
+	if (routine->SetRowFilter)
+	{
+		/* Install the row filter expression into the table builder context */
+		value = ExecEvalExpr(tstate->rowexpr, econtext, &isnull);
+		if (isnull)
+			ereport(ERROR,
+					(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
+					 errmsg("row filter expression must not be null")));
 
-	routine->SetRowFilter(tstate, TextDatumGetCString(value));
+		routine->SetRowFilter(tstate, TextDatumGetCString(value));
+	}
 
 	/*
 	 * Install the column filter expressions into the table builder context.
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index a791ebd6cd..5c72986017 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -1393,6 +1393,7 @@ _copyTableFunc(const TableFunc *from)
 {
 	TableFunc  *newnode = makeNode(TableFunc);
 
+	COPY_SCALAR_FIELD(functype);
 	COPY_NODE_FIELD(ns_uris);
 	COPY_NODE_FIELD(ns_names);
 	COPY_NODE_FIELD(docexpr);
@@ -1403,7 +1404,9 @@ _copyTableFunc(const TableFunc *from)
 	COPY_NODE_FIELD(colcollations);
 	COPY_NODE_FIELD(colexprs);
 	COPY_NODE_FIELD(coldefexprs);
+	COPY_NODE_FIELD(colvalexprs);
 	COPY_BITMAPSET_FIELD(notnulls);
+	COPY_NODE_FIELD(plan);
 	COPY_SCALAR_FIELD(ordinalitycol);
 	COPY_LOCATION_FIELD(location);
 
@@ -2682,6 +2685,76 @@ _copyJsonArgument(const JsonArgument *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTable
+ */
+static JsonTable *
+_copyJsonTable(const JsonTable *from)
+{
+	JsonTable *newnode = makeNode(JsonTable);
+
+	COPY_NODE_FIELD(common);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_error);
+	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableColumn
+ */
+static JsonTableColumn *
+_copyJsonTableColumn(const JsonTableColumn *from)
+{
+	JsonTableColumn *newnode = makeNode(JsonTableColumn);
+
+	COPY_SCALAR_FIELD(coltype);
+	COPY_STRING_FIELD(name);
+	COPY_NODE_FIELD(typeName);
+	COPY_STRING_FIELD(pathspec);
+	COPY_SCALAR_FIELD(format);
+	COPY_SCALAR_FIELD(wrapper);
+	COPY_SCALAR_FIELD(omit_quotes);
+	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(on_empty);
+	COPY_NODE_FIELD(on_error);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableParent
+ */
+static JsonTableParent *
+_copyJsonTableParent(const JsonTableParent *from)
+{
+	JsonTableParent *newnode = makeNode(JsonTableParent);
+
+	COPY_NODE_FIELD(path);
+	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(colMin);
+	COPY_SCALAR_FIELD(colMax);
+
+	return newnode;
+}
+
+/*
+ * _copyJsonTableSibling
+ */
+static JsonTableSibling *
+_copyJsonTableSibling(const JsonTableSibling *from)
+{
+	JsonTableSibling *newnode = makeNode(JsonTableSibling);
+
+	COPY_NODE_FIELD(larg);
+	COPY_NODE_FIELD(rarg);
+
+	return newnode;
+}
+
 /* ****************************************************************
  *						pathnodes.h copy functions
  *
@@ -5803,6 +5876,18 @@ copyObjectImpl(const void *from)
 		case T_JsonItemCoercions:
 			retval = _copyJsonItemCoercions(from);
 			break;
+		case T_JsonTable:
+			retval = _copyJsonTable(from);
+			break;
+		case T_JsonTableColumn:
+			retval = _copyJsonTableColumn(from);
+			break;
+		case T_JsonTableParent:
+			retval = _copyJsonTableParent(from);
+			break;
+		case T_JsonTableSibling:
+			retval = _copyJsonTableSibling(from);
+			break;
 
 			/*
 			 * RELATION NODES
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index c52cadb5d9..ee98f916d7 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -127,6 +127,7 @@ _equalRangeVar(const RangeVar *a, const RangeVar *b)
 static bool
 _equalTableFunc(const TableFunc *a, const TableFunc *b)
 {
+	COMPARE_SCALAR_FIELD(functype);
 	COMPARE_NODE_FIELD(ns_uris);
 	COMPARE_NODE_FIELD(ns_names);
 	COMPARE_NODE_FIELD(docexpr);
@@ -137,13 +138,65 @@ _equalTableFunc(const TableFunc *a, const TableFunc *b)
 	COMPARE_NODE_FIELD(colcollations);
 	COMPARE_NODE_FIELD(colexprs);
 	COMPARE_NODE_FIELD(coldefexprs);
+	COMPARE_NODE_FIELD(colvalexprs);
 	COMPARE_BITMAPSET_FIELD(notnulls);
+	COMPARE_NODE_FIELD(plan);
 	COMPARE_SCALAR_FIELD(ordinalitycol);
 	COMPARE_LOCATION_FIELD(location);
 
 	return true;
 }
 
+static bool
+_equalJsonTable(const JsonTable *a, const JsonTable *b)
+{
+	COMPARE_NODE_FIELD(common);
+	COMPARE_NODE_FIELD(columns);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_NODE_FIELD(alias);
+	COMPARE_SCALAR_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonTableColumn(const JsonTableColumn *a, const JsonTableColumn *b)
+{
+	COMPARE_SCALAR_FIELD(coltype);
+	COMPARE_STRING_FIELD(name);
+	COMPARE_NODE_FIELD(typeName);
+	COMPARE_STRING_FIELD(pathspec);
+	COMPARE_SCALAR_FIELD(format);
+	COMPARE_SCALAR_FIELD(wrapper);
+	COMPARE_SCALAR_FIELD(omit_quotes);
+	COMPARE_NODE_FIELD(columns);
+	COMPARE_NODE_FIELD(on_empty);
+	COMPARE_NODE_FIELD(on_error);
+	COMPARE_SCALAR_FIELD(location);
+
+	return true;
+}
+
+static bool
+_equalJsonTableParent(const JsonTableParent *a, const JsonTableParent *b)
+{
+	COMPARE_NODE_FIELD(path);
+	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(colMin);
+	COMPARE_SCALAR_FIELD(colMax);
+
+	return true;
+}
+
+static bool
+_equalJsonTableSibling(const JsonTableSibling *a, const JsonTableSibling *b)
+{
+	COMPARE_NODE_FIELD(larg);
+	COMPARE_NODE_FIELD(rarg);
+
+	return true;
+}
+
 static bool
 _equalIntoClause(const IntoClause *a, const IntoClause *b)
 {
@@ -3678,6 +3731,12 @@ equal(const void *a, const void *b)
 		case T_JsonItemCoercions:
 			retval = _equalJsonItemCoercions(a, b);
 			break;
+		case T_JsonTableParent:
+			retval = _equalJsonTableParent(a, b);
+			break;
+		case T_JsonTableSibling:
+			retval = _equalJsonTableSibling(a, b);
+			break;
 
 			/*
 			 * RELATION NODES
@@ -4291,6 +4350,12 @@ equal(const void *a, const void *b)
 		case T_JsonArgument:
 			retval = _equalJsonArgument(a, b);
 			break;
+		case T_JsonTable:
+			retval = _equalJsonTable(a, b);
+			break;
+		case T_JsonTableColumn:
+			retval = _equalJsonTableColumn(a, b);
+			break;
 
 		default:
 			elog(ERROR, "unrecognized node type: %d",
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 2fb2be2541..efb0bac946 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -2456,6 +2456,8 @@ expression_tree_walker(Node *node,
 					return true;
 				if (walker(tf->coldefexprs, context))
 					return true;
+				if (walker(tf->colvalexprs, context))
+					return true;
 			}
 			break;
 		case T_JsonValueExpr:
@@ -3489,6 +3491,7 @@ expression_tree_mutator(Node *node,
 				MUTATE(newnode->rowexpr, tf->rowexpr, Node *);
 				MUTATE(newnode->colexprs, tf->colexprs, List *);
 				MUTATE(newnode->coldefexprs, tf->coldefexprs, List *);
+				MUTATE(newnode->colvalexprs, tf->colvalexprs, List *);
 				return (Node *) newnode;
 			}
 			break;
@@ -4477,6 +4480,30 @@ raw_expression_tree_walker(Node *node,
 					return true;
 			}
 			break;
+		case T_JsonTable:
+			{
+				JsonTable  *jt = (JsonTable *) node;
+
+				if (walker(jt->common, context))
+					return true;
+				if (walker(jt->columns, context))
+					return true;
+			}
+			break;
+		case T_JsonTableColumn:
+			{
+				JsonTableColumn  *jtc = (JsonTableColumn *) node;
+
+				if (walker(jtc->typeName, context))
+					return true;
+				if (walker(jtc->on_empty, context))
+					return true;
+				if (walker(jtc->on_error, context))
+					return true;
+				if (jtc->coltype == JTC_NESTED && walker(jtc->columns, context))
+					return true;
+			}
+			break;
 		default:
 			elog(ERROR, "unrecognized node type: %d",
 				 (int) nodeTag(node));
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 23750d97ab..e5a725a636 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1091,6 +1091,7 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 {
 	WRITE_NODE_TYPE("TABLEFUNC");
 
+	WRITE_ENUM_FIELD(functype, TableFuncType);
 	WRITE_NODE_FIELD(ns_uris);
 	WRITE_NODE_FIELD(ns_names);
 	WRITE_NODE_FIELD(docexpr);
@@ -1101,7 +1102,9 @@ _outTableFunc(StringInfo str, const TableFunc *node)
 	WRITE_NODE_FIELD(colcollations);
 	WRITE_NODE_FIELD(colexprs);
 	WRITE_NODE_FIELD(coldefexprs);
+	WRITE_NODE_FIELD(colvalexprs);
 	WRITE_BITMAPSET_FIELD(notnulls);
+	WRITE_NODE_FIELD(plan);
 	WRITE_INT_FIELD(ordinalitycol);
 	WRITE_LOCATION_FIELD(location);
 }
@@ -1865,6 +1868,26 @@ _outJsonItemCoercions(StringInfo str, const JsonItemCoercions *node)
 	WRITE_NODE_FIELD(composite);
 }
 
+static void
+_outJsonTableParent(StringInfo str, const JsonTableParent *node)
+{
+	WRITE_NODE_TYPE("JSONTABPNODE");
+
+	WRITE_NODE_FIELD(path);
+	WRITE_NODE_FIELD(child);
+	WRITE_INT_FIELD(colMin);
+	WRITE_INT_FIELD(colMax);
+}
+
+static void
+_outJsonTableSibling(StringInfo str, const JsonTableSibling *node)
+{
+	WRITE_NODE_TYPE("JSONTABSNODE");
+
+	WRITE_NODE_FIELD(larg);
+	WRITE_NODE_FIELD(rarg);
+}
+
 /*****************************************************************************
  *
  *	Stuff from pathnodes.h.
@@ -4678,6 +4701,12 @@ outNode(StringInfo str, const void *obj)
 			case T_JsonItemCoercions:
 				_outJsonItemCoercions(str, obj);
 				break;
+			case T_JsonTableParent:
+				_outJsonTableParent(str, obj);
+				break;
+			case T_JsonTableSibling:
+				_outJsonTableSibling(str, obj);
+				break;
 
 			default:
 
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c15e81a362..3b63df6edc 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -533,6 +533,7 @@ _readTableFunc(void)
 {
 	READ_LOCALS(TableFunc);
 
+	READ_ENUM_FIELD(functype, TableFuncType);
 	READ_NODE_FIELD(ns_uris);
 	READ_NODE_FIELD(ns_names);
 	READ_NODE_FIELD(docexpr);
@@ -543,7 +544,9 @@ _readTableFunc(void)
 	READ_NODE_FIELD(colcollations);
 	READ_NODE_FIELD(colexprs);
 	READ_NODE_FIELD(coldefexprs);
+	READ_NODE_FIELD(colvalexprs);
 	READ_BITMAPSET_FIELD(notnulls);
+	READ_NODE_FIELD(plan);
 	READ_INT_FIELD(ordinalitycol);
 	READ_LOCATION_FIELD(location);
 
@@ -1494,6 +1497,30 @@ _readJsonExpr(void)
 	READ_DONE();
 }
 
+static JsonTableParent *
+_readJsonTableParent(void)
+{
+	READ_LOCALS(JsonTableParent);
+
+	READ_NODE_FIELD(path);
+	READ_NODE_FIELD(child);
+	READ_INT_FIELD(colMin);
+	READ_INT_FIELD(colMax);
+
+	READ_DONE();
+}
+
+static JsonTableSibling *
+_readJsonTableSibling(void)
+{
+	READ_LOCALS(JsonTableSibling);
+
+	READ_NODE_FIELD(larg);
+	READ_NODE_FIELD(rarg);
+
+	READ_DONE();
+}
+
 /*
  * _readJsonCoercion
  */
@@ -3151,6 +3178,10 @@ parseNodeString(void)
 		return_value = _readJsonCoercion();
 	else if (MATCH("JSONITEMCOERCIONS", 17))
 		return_value = _readJsonItemCoercions();
+	else if (MATCH("JSONTABPNODE", 12))
+		return_value = _readJsonTableParent();
+	else if (MATCH("JSONTABSNODE", 12))
+		return_value = _readJsonTableSibling();
 	else
 	{
 		elog(ERROR, "badly formatted node string \"%.32s\"...", token);
diff --git a/src/backend/parser/Makefile b/src/backend/parser/Makefile
index 5ddb9a92f0..56dafdd961 100644
--- a/src/backend/parser/Makefile
+++ b/src/backend/parser/Makefile
@@ -23,6 +23,7 @@ OBJS = \
 	parse_enr.o \
 	parse_expr.o \
 	parse_func.o \
+	parse_jsontable.o \
 	parse_node.o \
 	parse_oper.o \
 	parse_param.o \
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ae7b3f6bb8..78f63d15b9 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -670,15 +670,25 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_object_aggregate_constructor
 					json_array_aggregate_constructor
 					json_path_specification
+					json_table
+					json_table_column_definition
+					json_table_ordinality_column_definition
+					json_table_regular_column_definition
+					json_table_formatted_column_definition
+					json_table_exists_column_definition
+					json_table_nested_columns
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
 					json_array_aggregate_order_by_clause_opt
 					json_arguments
 					json_passing_clause_opt
+					json_table_columns_clause
+					json_table_column_definition_list
 
 %type <str>			json_table_path_name
 					json_as_path_name_clause_opt
+					json_table_column_path_specification_clause_opt
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
@@ -692,6 +702,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_behavior_true
 					json_behavior_false
 					json_behavior_unknown
+					json_behavior_empty
 					json_behavior_empty_array
 					json_behavior_empty_object
 					json_behavior_default
@@ -699,6 +710,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_query_behavior
 					json_exists_error_behavior
 					json_exists_error_clause_opt
+					json_table_error_behavior
+					json_table_error_clause_opt
 
 %type <on_behavior> json_value_on_behavior_clause_opt
 					json_query_on_behavior_clause_opt
@@ -773,7 +786,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
 
 	JOIN JSON JSON_ARRAY JSON_ARRAYAGG JSON_EXISTS JSON_OBJECT JSON_OBJECTAGG
-	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_VALUE
+	JSON_QUERY JSON_SCALAR JSON_SERIALIZE JSON_TABLE JSON_VALUE
 
 	KEY KEYS KEEP
 
@@ -783,8 +796,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	MAPPING MATCH MATERIALIZED MAXVALUE METHOD MINUTE_P MINVALUE MODE MONTH_P MOVE
 
-	NAME_P NAMES NATIONAL NATURAL NCHAR NEW NEXT NFC NFD NFKC NFKD NO NONE
-	NORMALIZE NORMALIZED
+	NAME_P NAMES NATIONAL NATURAL NCHAR NESTED NEW NEXT NFC NFD NFKC NFKD NO
+	NONE NORMALIZE NORMALIZED
 	NOT NOTHING NOTIFY NOTNULL NOWAIT NULL_P NULLIF
 	NULLS_P NUMERIC
 
@@ -792,7 +805,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -894,7 +907,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %nonassoc	UNBOUNDED		/* ideally would have same precedence as IDENT */
 %nonassoc	ERROR_P EMPTY_P DEFAULT ABSENT /* JSON error/empty behavior */
-%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON
+%nonassoc	FALSE_P KEEP OMIT PASSING TRUE_P UNKNOWN UNIQUE JSON COLUMNS
 %nonassoc	IDENT PARTITION RANGE ROWS GROUPS PRECEDING FOLLOWING CUBE ROLLUP
 %left		Op OPERATOR		/* multi-character ops and user-defined operators */
 %left		'+' '-'
@@ -919,6 +932,10 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
  */
 %left		JOIN CROSS LEFT FULL RIGHT INNER_P NATURAL
 
+%nonassoc	json_table_column
+%nonassoc	NESTED
+%left		PATH
+
 %nonassoc	empty_json_unique
 %left		WITHOUT WITH_LA_UNIQUE
 
@@ -12519,6 +12536,19 @@ table_ref:	relation_expr opt_alias_clause
 					$2->alias = $4;
 					$$ = (Node *) $2;
 				}
+			| json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $1);
+					jt->alias = $2;
+					$$ = (Node *) jt;
+				}
+			| LATERAL_P json_table opt_alias_clause
+				{
+					JsonTable *jt = castNode(JsonTable, $2);
+					jt->alias = $3;
+					jt->lateral = true;
+					$$ = (Node *) jt;
+				}
 		;
 
 
@@ -13070,6 +13100,8 @@ xmltable_column_option_el:
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(true), @1); }
 			| NULL_P
 				{ $$ = makeDefElem("is_not_null", (Node *) makeBoolean(false), @1); }
+			| PATH b_expr
+				{ $$ = makeDefElem("path", $2, @1); }
 		;
 
 xml_namespace_list:
@@ -15596,6 +15628,10 @@ json_behavior_unknown:
 			UNKNOWN		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_UNKNOWN, NULL); }
 		;
 
+json_behavior_empty:
+			EMPTY_P		{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_OBJECT, NULL); }
+		;
+
 json_behavior_empty_array:
 			EMPTY_P ARRAY	{ $$ = makeJsonBehavior(JSON_BEHAVIOR_EMPTY_ARRAY, NULL); }
 			/* non-standard, for Oracle compatibility only */
@@ -15710,6 +15746,153 @@ json_query_on_behavior_clause_opt:
 									{ $$.on_empty = NULL; $$.on_error = NULL; }
 		;
 
+json_table:
+			JSON_TABLE '('
+				json_api_common_syntax
+				json_table_columns_clause
+				json_table_error_clause_opt
+			')'
+				{
+					JsonTable *n = makeNode(JsonTable);
+					n->common = (JsonCommon *) $3;
+					n->columns = $4;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_columns_clause:
+			COLUMNS '('	json_table_column_definition_list ')' { $$ = $3; }
+		;
+
+json_table_column_definition_list:
+			json_table_column_definition
+				{ $$ = list_make1($1); }
+			| json_table_column_definition_list ',' json_table_column_definition
+				{ $$ = lappend($1, $3); }
+		;
+
+json_table_column_definition:
+			json_table_ordinality_column_definition		%prec json_table_column
+			| json_table_regular_column_definition 		%prec json_table_column
+			| json_table_formatted_column_definition	%prec json_table_column
+			| json_table_exists_column_definition		%prec json_table_column
+			| json_table_nested_columns
+		;
+
+json_table_ordinality_column_definition:
+			ColId FOR ORDINALITY
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FOR_ORDINALITY;
+					n->name = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_regular_column_definition:
+			ColId Typename
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_value_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_REGULAR;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = $4; /* JSW_NONE */
+					n->omit_quotes = $5; /* false */
+					n->pathspec = $3;
+					n->on_empty = $6.on_empty;
+					n->on_error = $6.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_exists_column_definition:
+			ColId Typename
+			EXISTS json_table_column_path_specification_clause_opt
+			json_exists_error_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_EXISTS;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+					n->wrapper = JSW_NONE;
+					n->omit_quotes = false;
+					n->pathspec = $4;
+					n->on_empty = NULL;
+					n->on_error = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_error_behavior:
+			json_behavior_error
+			| json_behavior_empty
+		;
+
+json_table_error_clause_opt:
+			json_table_error_behavior ON ERROR_P	{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_column_path_specification_clause_opt:
+			PATH Sconst								{ $$ = $2; }
+			| /* EMPTY */ %prec json_table_column	{ $$ = NULL; }
+		;
+
+json_table_formatted_column_definition:
+			ColId Typename FORMAT json_representation
+			json_table_column_path_specification_clause_opt
+			json_wrapper_clause_opt
+			json_quotes_clause_opt
+			json_query_on_behavior_clause_opt
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_FORMATTED;
+					n->name = $1;
+					n->typeName = $2;
+					n->format = castNode(JsonFormat, $4);
+					n->pathspec = $5;
+					n->wrapper = $6;
+					if (n->wrapper != JSW_NONE && $7 != JS_QUOTES_UNSPEC)
+						ereport(ERROR,
+								(errcode(ERRCODE_SYNTAX_ERROR),
+								 errmsg("SQL/JSON QUOTES behavior must not be specified when WITH WRAPPER is used"),
+								 parser_errposition(@7)));
+					n->omit_quotes = $7 == JS_QUOTES_OMIT;
+					n->on_empty = $8.on_empty;
+					n->on_error = $8.on_error;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_nested_columns:
+			NESTED path_opt Sconst json_table_columns_clause
+				{
+					JsonTableColumn *n = makeNode(JsonTableColumn);
+					n->coltype = JTC_NESTED;
+					n->pathspec = $3;
+					n->columns = $4;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+path_opt:
+			PATH									{ }
+			| /* EMPTY */							{ }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16553,6 +16736,7 @@ unreserved_keyword:
 			| MOVE
 			| NAME_P
 			| NAMES
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -16586,6 +16770,7 @@ unreserved_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -16749,6 +16934,7 @@ col_name_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| LEAST
 			| NATIONAL
@@ -17116,6 +17302,7 @@ bare_label_keyword:
 			| JSON_QUERY
 			| JSON_SCALAR
 			| JSON_SERIALIZE
+			| JSON_TABLE
 			| JSON_VALUE
 			| KEEP
 			| KEY
@@ -17153,6 +17340,7 @@ bare_label_keyword:
 			| NATIONAL
 			| NATURAL
 			| NCHAR
+			| NESTED
 			| NEW
 			| NEXT
 			| NFC
@@ -17196,6 +17384,7 @@ bare_label_keyword:
 			| PARTITION
 			| PASSING
 			| PASSWORD
+			| PATH
 			| PLACING
 			| PLANS
 			| POLICY
diff --git a/src/backend/parser/parse_clause.c b/src/backend/parser/parse_clause.c
index d8b14ba7cd..dafde68b20 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -696,7 +696,9 @@ transformRangeTableFunc(ParseState *pstate, RangeTableFunc *rtf)
 	char	  **names;
 	int			colno;
 
-	/* Currently only XMLTABLE is supported */
+	/* Currently only XMLTABLE and JSON_TABLE are supported */
+
+	tf->functype = TFT_XMLTABLE;
 	constructName = "XMLTABLE";
 	docType = XMLOID;
 
@@ -1100,13 +1102,17 @@ transformFromClauseItem(ParseState *pstate, Node *n,
 		rtr->rtindex = nsitem->p_rtindex;
 		return (Node *) rtr;
 	}
-	else if (IsA(n, RangeTableFunc))
+	else if (IsA(n, RangeTableFunc) || IsA(n, JsonTable))
 	{
 		/* table function is like a plain relation */
 		RangeTblRef *rtr;
 		ParseNamespaceItem *nsitem;
 
-		nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		if (IsA(n, RangeTableFunc))
+			nsitem = transformRangeTableFunc(pstate, (RangeTableFunc *) n);
+		else
+			nsitem = transformJsonTable(pstate, (JsonTable *) n);
+
 		*top_nsitem = nsitem;
 		*namespace = list_make1(nsitem);
 		rtr = makeNode(RangeTblRef);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 18622fd013..3ea45d882a 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4093,7 +4093,7 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	Node	   *pathspec;
 	JsonFormatType format;
 
-	if (func->common->pathname)
+	if (func->common->pathname && func->op != IS_JSON_TABLE)
 		ereport(ERROR,
 				(errcode(ERRCODE_SYNTAX_ERROR),
 				 errmsg("JSON_TABLE path name is not allowed here"),
@@ -4131,14 +4131,13 @@ transformJsonExprCommon(ParseState *pstate, JsonFuncExpr *func)
 	transformJsonPassingArgs(pstate, format, func->common->passing,
 							 &jsexpr->passing_values, &jsexpr->passing_names);
 
-	if (func->op != IS_JSON_EXISTS)
+	if (func->op != IS_JSON_EXISTS && func->op != IS_JSON_TABLE)
 		jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
 												 JSON_BEHAVIOR_NULL);
 
 	jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
-											 func->op == IS_JSON_EXISTS ?
-											 JSON_BEHAVIOR_FALSE :
-											 JSON_BEHAVIOR_NULL);
+		func->op == IS_JSON_EXISTS ? JSON_BEHAVIOR_FALSE :
+		func->op == IS_JSON_TABLE ? JSON_BEHAVIOR_EMPTY : JSON_BEHAVIOR_NULL);
 
 	return jsexpr;
 }
@@ -4439,6 +4438,21 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
 					jsexpr->result_coercion->expr = NULL;
 			}
 			break;
+
+		case IS_JSON_TABLE:
+			jsexpr->returning = makeNode(JsonReturning);
+			jsexpr->returning->format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+			jsexpr->returning->typid = exprType(contextItemExpr);
+			jsexpr->returning->typmod = -1;
+
+			if (jsexpr->returning->typid != JSONBOID)
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("JSON_TABLE() is not yet implemented for json type"),
+						 errhint("Try casting the argument to jsonb"),
+						 parser_errposition(pstate, func->location)));
+
+			break;
 	}
 
 	if (exprType(contextItemExpr) != JSONBOID)
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
new file mode 100644
index 0000000000..becadc4d3b
--- /dev/null
+++ b/src/backend/parser/parse_jsontable.c
@@ -0,0 +1,466 @@
+/*-------------------------------------------------------------------------
+ *
+ * parse_jsontable.c
+ *	  parsing of JSON_TABLE
+ *
+ * Portions Copyright (c) 1996-2021, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ *	  src/backend/parser/parse_jsontable.c
+ *
+ *-------------------------------------------------------------------------
+ */
+
+#include "postgres.h"
+
+#include "catalog/pg_collation.h"
+#include "catalog/pg_type.h"
+#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/optimizer.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_collate.h"
+#include "parser/parse_expr.h"
+#include "parser/parse_relation.h"
+#include "parser/parse_type.h"
+#include "utils/builtins.h"
+#include "utils/json.h"
+#include "utils/lsyscache.h"
+
+/* Context for JSON_TABLE transformation */
+typedef struct JsonTableContext
+{
+	ParseState *pstate;				/* parsing state */
+	JsonTable  *table;				/* untransformed node */
+	TableFunc  *tablefunc;			/* transformed node	*/
+	List	   *pathNames;			/* list of all path and columns names */
+	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
+} JsonTableContext;
+
+static JsonTableParent * transformJsonTableColumns(JsonTableContext *cxt,
+													   List *columns,
+													   char *pathSpec,
+													   int location);
+
+static Node *
+makeStringConst(char *str, int location)
+{
+	A_Const *n = makeNode(A_Const);
+
+	n->val.node.type = T_String;
+	n->val.sval.sval = str;
+	n->location = location;
+
+	return (Node *)n;
+}
+
+/*
+ * Transform JSON_TABLE column
+ *   - regular column into JSON_VALUE()
+ *   - FORMAT JSON column into JSON_QUERY()
+ *   - EXISTS column into JSON_EXISTS()
+ */
+static Node *
+transformJsonTableColumn(JsonTableColumn *jtc, Node *contextItemExpr,
+						 List *passingArgs, bool errorOnError)
+{
+	JsonFuncExpr *jfexpr = makeNode(JsonFuncExpr);
+	JsonCommon *common = makeNode(JsonCommon);
+	JsonOutput *output = makeNode(JsonOutput);
+	JsonPathSpec pathspec;
+	JsonFormat *default_format;
+
+	jfexpr->op =
+		jtc->coltype == JTC_REGULAR ? IS_JSON_VALUE :
+		jtc->coltype == JTC_EXISTS ? IS_JSON_EXISTS : IS_JSON_QUERY;
+	jfexpr->common = common;
+	jfexpr->output = output;
+	jfexpr->on_empty = jtc->on_empty;
+	jfexpr->on_error = jtc->on_error;
+	if (!jfexpr->on_error && errorOnError)
+		jfexpr->on_error = makeJsonBehavior(JSON_BEHAVIOR_ERROR, NULL);
+	jfexpr->omit_quotes = jtc->omit_quotes;
+	jfexpr->wrapper = jtc->wrapper;
+	jfexpr->location = jtc->location;
+
+	output->typeName = jtc->typeName;
+	output->returning = makeNode(JsonReturning);
+	output->returning->format = jtc->format;
+
+	default_format = makeJsonFormat(JS_FORMAT_DEFAULT, JS_ENC_DEFAULT, -1);
+
+	common->pathname = NULL;
+	common->expr = makeJsonValueExpr((Expr *) contextItemExpr, default_format);
+	common->passing = passingArgs;
+
+	if (jtc->pathspec)
+		pathspec = jtc->pathspec;
+	else
+	{
+		/* Construct default path as '$."column_name"' */
+		StringInfoData path;
+
+		initStringInfo(&path);
+
+		appendStringInfoString(&path, "$.");
+		escape_json(&path, jtc->name);
+
+		pathspec = path.data;
+	}
+
+	common->pathspec = makeStringConst(pathspec, -1);
+
+	return (Node *) jfexpr;
+}
+
+static bool
+isJsonTablePathNameDuplicate(JsonTableContext *cxt, const char *pathname)
+{
+	ListCell *lc;
+
+	foreach(lc, cxt->pathNames)
+	{
+		if (!strcmp(pathname, (const char *) lfirst(lc)))
+			return true;
+	}
+
+	return false;
+}
+
+/* Register the column name in the path name list. */
+static void
+registerJsonTableColumn(JsonTableContext *cxt, char *colname)
+{
+	if (isJsonTablePathNameDuplicate(cxt, colname))
+		ereport(ERROR,
+				(errcode(ERRCODE_DUPLICATE_ALIAS),
+				 errmsg("duplicate JSON_TABLE column name: %s", colname),
+				 errhint("JSON_TABLE column names must be distinct from one another")));
+
+	cxt->pathNames = lappend(cxt->pathNames, colname);
+}
+
+/* Recursively register all nested column names in the path name list. */
+static void
+registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED)
+			registerAllJsonTableColumns(cxt, jtc->columns);
+		else
+			registerJsonTableColumn(cxt, jtc->name);
+	}
+}
+
+static Node *
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+{
+	JsonTableParent *node;
+
+	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
+									 jtc->location);
+
+	return (Node *) node;
+}
+
+static Node *
+makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+{
+	JsonTableSibling *join = makeNode(JsonTableSibling);
+
+	join->larg = lnode;
+	join->rarg = rnode;
+
+	return (Node *) join;
+}
+
+/*
+ * Recursively transform child (nested) JSON_TABLE columns.
+ *
+ * Child columns are transformed into a binary tree of union-joined
+ * JsonTableSiblings.
+ */
+static Node *
+transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+{
+	Node	   *res = NULL;
+	ListCell   *lc;
+
+	/* transform all nested columns into union join */
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+		Node	   *node;
+
+		if (jtc->coltype != JTC_NESTED)
+			continue;
+
+		node = transformNestedJsonTableColumn(cxt, jtc);
+
+		/* join transformed node with previous sibling nodes */
+		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+	}
+
+	return res;
+}
+
+/* Check whether type is json/jsonb, array, or record. */
+static bool
+typeIsComposite(Oid typid)
+{
+	char typtype;
+	
+	if (typid == JSONOID ||
+		typid == JSONBOID ||
+		typid == RECORDOID ||
+		type_is_array(typid))
+		return true;
+
+	typtype = get_typtype(typid);
+
+	if (typtype ==	TYPTYPE_COMPOSITE)
+		return true;
+	
+	if (typtype == TYPTYPE_DOMAIN)
+		return typeIsComposite(getBaseType(typid));
+
+	return false;
+}
+
+/* Append transformed non-nested JSON_TABLE columns to the TableFunc node */
+static void
+appendJsonTableColumns(JsonTableContext *cxt, List *columns)
+{
+	ListCell   *col;
+	ParseState *pstate = cxt->pstate;
+	JsonTable  *jt = cxt->table;
+	TableFunc  *tf = cxt->tablefunc;
+	bool		errorOnError = jt->on_error &&
+							   jt->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	foreach(col, columns)
+	{
+		JsonTableColumn *rawc = castNode(JsonTableColumn, lfirst(col));
+		Oid			typid;
+		int32		typmod;
+		Node	   *colexpr;
+
+		if (rawc->name)
+		{
+			/* make sure column names are unique */
+			ListCell *colname;
+
+			foreach(colname, tf->colnames)
+				if (!strcmp((const char *) colname, rawc->name))
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("column name \"%s\" is not unique",
+									rawc->name),
+							 parser_errposition(pstate, rawc->location)));
+
+			tf->colnames = lappend(tf->colnames,
+								   makeString(pstrdup(rawc->name)));
+		}
+
+		/*
+		 * Determine the type and typmod for the new column. FOR
+		 * ORDINALITY columns are INTEGER by standard; the others are
+		 * user-specified.
+		 */
+		switch (rawc->coltype)
+		{
+			case JTC_FOR_ORDINALITY:
+				colexpr = NULL;
+				typid = INT4OID;
+				typmod = -1;
+				break;
+
+			case JTC_REGULAR:
+				typenameTypeIdAndMod(pstate, rawc->typeName, &typid, &typmod);
+
+				/*
+				 * Use implicit FORMAT JSON for composite types (arrays and
+				 * records)
+				 */
+				if (typeIsComposite(typid))
+					rawc->coltype = JTC_FORMATTED;
+				else if (rawc->wrapper != JSW_NONE)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use WITH WRAPPER clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+				else if (rawc->omit_quotes)
+					ereport(ERROR,
+							(errcode(ERRCODE_SYNTAX_ERROR),
+							 errmsg("cannot use OMIT QUOTES clause with scalar columns"),
+							 parser_errposition(pstate, rawc->location)));
+
+				/* FALLTHROUGH */
+			case JTC_EXISTS:
+			case JTC_FORMATTED:
+				{
+					Node	   *je;
+					CaseTestExpr *param = makeNode(CaseTestExpr);
+
+					param->collation = InvalidOid;
+					param->typeId = cxt->contextItemTypid;
+					param->typeMod = -1;
+
+					je = transformJsonTableColumn(rawc, (Node *) param,
+												  NIL, errorOnError);
+
+					colexpr = transformExpr(pstate, je, EXPR_KIND_FROM_FUNCTION);
+					assign_expr_collations(pstate, colexpr);
+
+					typid = exprType(colexpr);
+					typmod = exprTypmod(colexpr);
+					break;
+				}
+
+			case JTC_NESTED:
+				continue;
+
+			default:
+				elog(ERROR, "unknown JSON_TABLE column type: %d", rawc->coltype);
+				break;
+		}
+
+		tf->coltypes = lappend_oid(tf->coltypes, typid);
+		tf->coltypmods = lappend_int(tf->coltypmods, typmod);
+		tf->colcollations = lappend_oid(tf->colcollations,
+										type_is_collatable(typid)
+											? DEFAULT_COLLATION_OID
+											: InvalidOid);
+		tf->colvalexprs = lappend(tf->colvalexprs, colexpr);
+	}
+}
+
+/*
+ * Create transformed JSON_TABLE parent plan node by appending all non-nested
+ * columns to the TableFunc node and remembering their indices in the
+ * colvalexprs list.
+ */
+static JsonTableParent *
+makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
+{
+	JsonTableParent *node = makeNode(JsonTableParent);
+
+	node->path = makeConst(JSONPATHOID, -1, InvalidOid, -1,
+						   DirectFunctionCall1(jsonpath_in,
+											   CStringGetDatum(pathSpec)),
+						   false, false);
+
+	/* save start of column range */
+	node->colMin = list_length(cxt->tablefunc->colvalexprs);
+
+	appendJsonTableColumns(cxt, columns);
+
+	/* save end of column range */
+	node->colMax = list_length(cxt->tablefunc->colvalexprs) - 1;
+
+	node->errorOnError =
+		cxt->table->on_error &&
+		cxt->table->on_error->btype == JSON_BEHAVIOR_ERROR;
+
+	return node;
+}
+
+static JsonTableParent *
+transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+						  int location)
+{
+	JsonTableParent *node;
+
+	/* transform only non-nested columns */
+	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+
+	/* transform recursively nested columns */
+	node->child = transformJsonTableChildColumns(cxt, columns);
+
+	return node;
+}
+
+/*
+ * transformJsonTable -
+ *			Transform a raw JsonTable into TableFunc.
+ *
+ * Transform the document-generating expression, the row-generating expression,
+ * the column-generating expressions, and the default value expressions.
+ */
+ParseNamespaceItem *
+transformJsonTable(ParseState *pstate, JsonTable *jt)
+{
+	JsonTableContext cxt;
+	TableFunc  *tf = makeNode(TableFunc);
+	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonCommon *jscommon;
+	char	   *rootPath;
+	bool		is_lateral;
+
+	cxt.pstate = pstate;
+	cxt.table = jt;
+	cxt.tablefunc = tf;
+	cxt.pathNames = NIL;
+
+	registerAllJsonTableColumns(&cxt, jt->columns);
+
+	jscommon = copyObject(jt->common);
+	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
+
+	jfe->op = IS_JSON_TABLE;
+	jfe->common = jscommon;
+	jfe->on_error = jt->on_error;
+	jfe->location = jt->common->location;
+
+	/*
+	 * We make lateral_only names of this level visible, whether or not the
+	 * RangeTableFunc is explicitly marked LATERAL.  This is needed for SQL
+	 * spec compliance and seems useful on convenience grounds for all
+	 * functions in FROM.
+	 *
+	 * (LATERAL can't nest within a single pstate level, so we don't need
+	 * save/restore logic here.)
+	 */
+	Assert(!pstate->p_lateral_active);
+	pstate->p_lateral_active = true;
+
+	tf->functype = TFT_JSON_TABLE;
+	tf->docexpr = transformExpr(pstate, (Node *) jfe, EXPR_KIND_FROM_FUNCTION);
+
+	cxt.contextItemTypid = exprType(tf->docexpr);
+
+	if (!IsA(jt->common->pathspec, A_Const) ||
+		castNode(A_Const, jt->common->pathspec)->val.node.type != T_String)
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("only string constants supported in JSON_TABLE path specification"),
+				 parser_errposition(pstate,
+									exprLocation(jt->common->pathspec))));
+
+	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
+
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+												  jt->common->location);
+
+	tf->ordinalitycol = -1;		/* undefine ordinality column number */
+	tf->location = jt->location;
+
+	pstate->p_lateral_active = false;
+
+	/*
+	 * Mark the RTE as LATERAL if the user said LATERAL explicitly, or if
+	 * there are any lateral cross-references in it.
+	 */
+	is_lateral = jt->lateral || contain_vars_of_level((Node *) tf, 0);
+
+	return addRangeTableEntryForTableFunc(pstate,
+										  tf, jt->alias, is_lateral, true);
+}
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index cb9e177b5e..e06c23d0de 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -1978,7 +1978,8 @@ addRangeTableEntryForTableFunc(ParseState *pstate,
 							   bool inFromCl)
 {
 	RangeTblEntry *rte = makeNode(RangeTblEntry);
-	char	   *refname = alias ? alias->aliasname : pstrdup("xmltable");
+	char	   *refname = alias ? alias->aliasname :
+		pstrdup(tf->functype == TFT_XMLTABLE ? "xmltable" : "json_table");
 	Alias	   *eref;
 	int			numaliases;
 
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 829c0f9497..7cc5020861 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1992,6 +1992,9 @@ FigureColnameInternal(Node *node, char **name)
 				case IS_JSON_EXISTS:
 					*name = "json_exists";
 					return 2;
+				case IS_JSON_TABLE:
+					*name = "json_table";
+					return 2;
 			}
 			break;
 		default:
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index 7811fa31e0..c55b3aae02 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -61,9 +61,11 @@
 
 #include "catalog/pg_collation.h"
 #include "catalog/pg_type.h"
+#include "executor/execExpr.h"
 #include "funcapi.h"
 #include "lib/stringinfo.h"
 #include "miscadmin.h"
+#include "nodes/nodeFuncs.h"
 #include "regex/regex.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
@@ -74,6 +76,8 @@
 #include "utils/guc.h"
 #include "utils/json.h"
 #include "utils/jsonpath.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/timestamp.h"
 #include "utils/varlena.h"
 
@@ -155,6 +159,57 @@ typedef struct JsonValueListIterator
 	ListCell   *next;
 } JsonValueListIterator;
 
+/* Structures for JSON_TABLE execution  */
+typedef struct JsonTableScanState JsonTableScanState;
+typedef struct JsonTableJoinState JsonTableJoinState;
+
+struct JsonTableScanState
+{
+	JsonTableScanState *parent;
+	JsonTableJoinState *nested;
+	MemoryContext mcxt;
+	JsonPath   *path;
+	List	   *args;
+	JsonValueList found;
+	JsonValueListIterator iter;
+	Datum		current;
+	int			ordinal;
+	bool		currentIsNull;
+	bool		errorOnError;
+	bool		advanceNested;
+	bool		reset;
+};
+
+struct JsonTableJoinState
+{
+	union
+	{
+		struct
+		{
+			JsonTableJoinState *left;
+			JsonTableJoinState *right;
+			bool		advanceRight;
+		}			join;
+		JsonTableScanState scan;
+	}			u;
+	bool		is_join;
+};
+
+/* random number to identify JsonTableContext */
+#define JSON_TABLE_CONTEXT_MAGIC	418352867
+
+typedef struct JsonTableContext
+{
+	int			magic;
+	struct
+	{
+		ExprState  *expr;
+		JsonTableScanState *scan;
+	}		   *colexprs;
+	JsonTableScanState root;
+	bool		empty;
+} JsonTableContext;
+
 /* strict/lax flags is decomposed into four [un]wrap/error flags */
 #define jspStrictAbsenseOfErrors(cxt)	(!(cxt)->laxMode)
 #define jspAutoUnwrap(cxt)				((cxt)->laxMode)
@@ -245,6 +300,7 @@ static JsonPathExecResult getArrayIndex(JsonPathExecContext *cxt,
 										JsonPathItem *jsp, JsonbValue *jb, int32 *index);
 static JsonBaseObjectInfo setBaseObject(JsonPathExecContext *cxt,
 										JsonbValue *jbv, int32 id);
+static void JsonValueListClear(JsonValueList *jvl);
 static void JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv);
 static int	JsonValueListLength(const JsonValueList *jvl);
 static bool JsonValueListIsEmpty(JsonValueList *jvl);
@@ -262,6 +318,12 @@ static JsonbValue *wrapItemsInArray(const JsonValueList *items);
 static int	compareDatetime(Datum val1, Oid typid1, Datum val2, Oid typid2,
 							bool useTz, bool *have_error);
 
+
+static JsonTableJoinState *JsonTableInitPlanState(JsonTableContext *cxt,
+									Node *plan, JsonTableScanState *parent);
+static bool JsonTableNextRow(JsonTableScanState *scan);
+
+
 /****************** User interface to JsonPath executor ********************/
 
 /*
@@ -2458,6 +2520,13 @@ setBaseObject(JsonPathExecContext *cxt, JsonbValue *jbv, int32 id)
 	return baseObject;
 }
 
+static void
+JsonValueListClear(JsonValueList *jvl)
+{
+	jvl->singleton = NULL;
+	jvl->list = NULL;
+}
+
 static void
 JsonValueListAppend(JsonValueList *jvl, JsonbValue *jbv)
 {
@@ -3067,3 +3136,370 @@ JsonItemFromDatum(Datum val, Oid typid, int32 typmod, JsonbValue *res)
 							"casted to supported jsonpath types.")));
 	}
 }
+
+/************************ JSON_TABLE functions ***************************/
+
+/*
+ * Returns private data from executor state. Ensure validity by check with
+ * MAGIC number.
+ */
+static inline JsonTableContext *
+GetJsonTableContext(TableFuncScanState *state, const char *fname)
+{
+	JsonTableContext *result;
+
+	if (!IsA(state, TableFuncScanState))
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+	result = (JsonTableContext *) state->opaque;
+	if (result->magic != JSON_TABLE_CONTEXT_MAGIC)
+		elog(ERROR, "%s called with invalid TableFuncScanState", fname);
+
+	return result;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static void
+JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
+					   JsonTableParent *node, JsonTableScanState *parent,
+					   List *args, MemoryContext mcxt)
+{
+	int			i;
+
+	scan->parent = parent;
+	scan->errorOnError = node->errorOnError;
+	scan->path = DatumGetJsonPathP(node->path->constvalue);
+	scan->args = args;
+	scan->mcxt = AllocSetContextCreate(mcxt, "JsonTableContext",
+									   ALLOCSET_DEFAULT_SIZES);
+	scan->nested = node->child ?
+		JsonTableInitPlanState(cxt, node->child, scan) : NULL;
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+
+	for (i = node->colMin; i <= node->colMax; i++)
+		cxt->colexprs[i].scan = scan;
+}
+
+/* Recursively initialize JSON_TABLE scan state */
+static JsonTableJoinState *
+JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
+					   JsonTableScanState *parent)
+{
+	JsonTableJoinState *state = palloc0(sizeof(*state));
+
+	if (IsA(plan, JsonTableSibling))
+	{
+		JsonTableSibling *join = castNode(JsonTableSibling, plan);
+
+		state->is_join = true;
+		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
+		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
+	}
+	else
+	{
+		JsonTableParent *node = castNode(JsonTableParent, plan);
+
+		state->is_join = false;
+
+		JsonTableInitScanState(cxt, &state->u.scan, node, parent,
+							   parent->args, parent->mcxt);
+	}
+
+	return state;
+}
+
+/*
+ * JsonTableInitOpaque
+ *		Fill in TableFuncScanState->opaque for JsonTable processor
+ */
+static void
+JsonTableInitOpaque(TableFuncScanState *state, int natts)
+{
+	JsonTableContext *cxt;
+	PlanState  *ps = &state->ss.ps;
+	TableFuncScan  *tfs = castNode(TableFuncScan, ps->plan);
+	TableFunc  *tf = tfs->tablefunc;
+	JsonExpr   *ci = castNode(JsonExpr, tf->docexpr);
+	JsonTableParent *root = castNode(JsonTableParent, tf->plan);
+	List	   *args = NIL;
+	ListCell   *lc;
+	int			i;
+
+	cxt = palloc0(sizeof(JsonTableContext));
+	cxt->magic = JSON_TABLE_CONTEXT_MAGIC;
+
+	if (ci->passing_values)
+	{
+		ListCell   *exprlc;
+		ListCell   *namelc;
+
+		forboth(exprlc, ci->passing_values,
+				namelc, ci->passing_names)
+		{
+			Expr	   *expr = (Expr *) lfirst(exprlc);
+			String	   *name = lfirst_node(String, namelc);
+			JsonPathVariableEvalContext *var = palloc(sizeof(*var));
+
+			var->name = pstrdup(name->sval);
+			var->typid = exprType((Node *) expr);
+			var->typmod = exprTypmod((Node *) expr);
+			var->estate = ExecInitExpr(expr, ps);
+			var->econtext = ps->ps_ExprContext;
+			var->mcxt = CurrentMemoryContext;
+			var->evaluated = false;
+			var->value = (Datum) 0;
+			var->isnull = true;
+
+			args = lappend(args, var);
+		}
+	}
+
+	cxt->colexprs = palloc(sizeof(*cxt->colexprs) *
+						   list_length(tf->colvalexprs));
+
+	JsonTableInitScanState(cxt, &cxt->root, root, NULL, args,
+						   CurrentMemoryContext);
+
+	i = 0;
+
+	foreach(lc, tf->colvalexprs)
+	{
+		Expr	   *expr = lfirst(lc);
+
+		cxt->colexprs[i].expr =
+			ExecInitExprWithCaseValue(expr, ps,
+									  &cxt->colexprs[i].scan->current,
+									  &cxt->colexprs[i].scan->currentIsNull);
+
+		i++;
+	}
+
+	state->opaque = cxt;
+}
+
+/* Reset scan iterator to the beginning of the item list */
+static void
+JsonTableRescan(JsonTableScanState *scan)
+{
+	JsonValueListInitIterator(&scan->found, &scan->iter);
+	scan->current = PointerGetDatum(NULL);
+	scan->currentIsNull = true;
+	scan->advanceNested = false;
+	scan->ordinal = 0;
+}
+
+/* Reset context item of a scan, execute JSON path and reset a scan */
+static void
+JsonTableResetContextItem(JsonTableScanState *scan, Datum item)
+{
+	MemoryContext oldcxt;
+	JsonPathExecResult res;
+	Jsonb		*js = (Jsonb *) DatumGetJsonbP(item);
+
+	JsonValueListClear(&scan->found);
+
+	MemoryContextResetOnly(scan->mcxt);
+
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+
+	res = executeJsonPath(scan->path, scan->args, EvalJsonPathVar, js,
+						  scan->errorOnError, &scan->found, false /* FIXME */);
+
+	MemoryContextSwitchTo(oldcxt);
+
+	if (jperIsError(res))
+	{
+		Assert(!scan->errorOnError);
+		JsonValueListClear(&scan->found);	/* EMPTY ON ERROR case */
+	}
+
+	JsonTableRescan(scan);
+}
+
+/*
+ * JsonTableSetDocument
+ *		Install the input document
+ */
+static void
+JsonTableSetDocument(TableFuncScanState *state, Datum value)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableSetDocument");
+
+	JsonTableResetContextItem(&cxt->root, value);
+}
+
+/*
+ * Fetch next row from a union joined scan.
+ *
+ * Returns false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextJoinRow(JsonTableJoinState *state)
+{
+	if (!state->is_join)
+		return JsonTableNextRow(&state->u.scan);
+
+	if (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		if (JsonTableNextJoinRow(state->u.join.left))
+			return true;
+
+		state->u.join.advanceRight = true;	/* next inner row */
+	}
+
+	/* fetch next inner row */
+	return JsonTableNextJoinRow(state->u.join.right);
+}
+
+/* Recursively set 'reset' flag of scan and its child nodes */
+static void
+JsonTableJoinReset(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableJoinReset(state->u.join.left);
+		JsonTableJoinReset(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		state->u.scan.reset = true;
+		state->u.scan.advanceNested = false;
+
+		if (state->u.scan.nested)
+			JsonTableJoinReset(state->u.scan.nested);
+	}
+}
+
+/*
+ * Fetch next row from a simple scan with outer joined nested subscans.
+ *
+ * Returns false at the end of a scan, true otherwise.
+ */
+static bool
+JsonTableNextRow(JsonTableScanState *scan)
+{
+	JsonbValue *jbv;
+	MemoryContext oldcxt;
+
+	/* reset context item if requested */
+	if (scan->reset)
+	{
+		Assert(!scan->parent->currentIsNull);
+		JsonTableResetContextItem(scan, scan->parent->current);
+		scan->reset = false;
+	}
+
+	if (scan->advanceNested)
+	{
+		/* fetch next nested row */
+		if (JsonTableNextJoinRow(scan->nested))
+			return true;
+
+		scan->advanceNested = false;
+	}
+
+	/* fetch next row */
+	jbv = JsonValueListNext(&scan->found, &scan->iter);
+
+	if (!jbv)
+	{
+		scan->current = PointerGetDatum(NULL);
+		scan->currentIsNull = true;
+		return false;	/* end of scan */
+	}
+
+	/* set current row item */
+	oldcxt = MemoryContextSwitchTo(scan->mcxt);
+	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+	scan->currentIsNull = false;
+	MemoryContextSwitchTo(oldcxt);
+
+	scan->ordinal++;
+
+	if (scan->nested)
+	{
+		JsonTableJoinReset(scan->nested);
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+	}
+
+	return true;
+}
+
+/*
+ * JsonTableFetchRow
+ *		Prepare the next "current" tuple for upcoming GetValue calls.
+ *		Returns FALSE if the row-filter expression returned no more rows.
+ */
+static bool
+JsonTableFetchRow(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableFetchRow");
+
+	if (cxt->empty)
+		return false;
+
+	return JsonTableNextRow(&cxt->root);
+}
+
+/*
+ * JsonTableGetValue
+ *		Return the value for column number 'colnum' for the current row.
+ *
+ * This leaks memory, so be sure to reset often the context in which it's
+ * called.
+ */
+static Datum
+JsonTableGetValue(TableFuncScanState *state, int colnum,
+				  Oid typid, int32 typmod, bool *isnull)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableGetValue");
+	ExprContext *econtext = state->ss.ps.ps_ExprContext;
+	ExprState  *estate = cxt->colexprs[colnum].expr;
+	JsonTableScanState *scan = cxt->colexprs[colnum].scan;
+	Datum		result;
+
+	if (scan->currentIsNull) /* NULL from outer/union join */
+	{
+		result = (Datum) 0;
+		*isnull = true;
+	}
+	else if (estate)	/* regular column */
+	{
+		result = ExecEvalExpr(estate, econtext, isnull);
+	}
+	else
+	{
+		result = Int32GetDatum(scan->ordinal);	/* ordinality column */
+		*isnull = false;
+	}
+
+	return result;
+}
+
+/*
+ * JsonTableDestroyOpaque
+ */
+static void
+JsonTableDestroyOpaque(TableFuncScanState *state)
+{
+	JsonTableContext *cxt = GetJsonTableContext(state, "JsonTableDestroyOpaque");
+
+	/* not valid anymore */
+	cxt->magic = 0;
+
+	state->opaque = NULL;
+}
+
+const TableFuncRoutine JsonbTableRoutine =
+{
+	JsonTableInitOpaque,
+	JsonTableSetDocument,
+	NULL,
+	NULL,
+	NULL,
+	JsonTableFetchRow,
+	JsonTableGetValue,
+	JsonTableDestroyOpaque
+};
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index e9b7970acc..43d04644e1 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -498,6 +498,8 @@ static char *flatten_reloptions(Oid relid);
 static void get_reloptions(StringInfo buf, Datum reloptions);
 static void get_json_path_spec(Node *path_spec, deparse_context *context,
 							   bool showimplicit);
+static void get_json_table_columns(TableFunc *tf, JsonTableParent *node,
+								   deparse_context *context, bool showimplicit);
 
 #define only_marker(rte)  ((rte)->inh ? "" : "ONLY ")
 
@@ -8480,7 +8482,8 @@ get_json_behavior(JsonBehavior *behavior, deparse_context *context,
 /*
  * get_json_expr_options
  *
- * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS.
+ * Parse back common options for JSON_QUERY, JSON_VALUE, JSON_EXISTS and
+ * JSON_TABLE columns.
  */
 static void
 get_json_expr_options(JsonExpr *jsexpr, deparse_context *context,
@@ -9727,6 +9730,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_JSON_EXISTS:
 						appendStringInfoString(buf, "JSON_EXISTS(");
 						break;
+					default:
+						elog(ERROR, "unexpected JsonExpr type: %d", jexpr->op);
+						break;
 				}
 
 				get_rule_expr(jexpr->formatted_expr, context, showimplicit);
@@ -11001,16 +11007,14 @@ get_sublink_expr(SubLink *sublink, deparse_context *context)
 
 
 /* ----------
- * get_tablefunc			- Parse back a table function
+ * get_xmltable			- Parse back a XMLTABLE function
  * ----------
  */
 static void
-get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+get_xmltable(TableFunc *tf, deparse_context *context, bool showimplicit)
 {
 	StringInfo	buf = context->buf;
 
-	/* XMLTABLE is the only existing implementation.  */
-
 	appendStringInfoString(buf, "XMLTABLE(");
 
 	if (tf->ns_uris != NIL)
@@ -11101,6 +11105,220 @@ get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
 	appendStringInfoChar(buf, ')');
 }
 
+/*
+ * get_json_nested_columns - Parse back nested JSON_TABLE columns
+ */
+static void
+get_json_table_nested_columns(TableFunc *tf, Node *node,
+							  deparse_context *context, bool showimplicit,
+							  bool needcomma)
+{
+	if (IsA(node, JsonTableSibling))
+	{
+		JsonTableSibling *n = (JsonTableSibling *) node;
+
+		get_json_table_nested_columns(tf, n->larg, context, showimplicit,
+									  needcomma);
+		get_json_table_nested_columns(tf, n->rarg, context, showimplicit, true);
+	}
+	else
+	{
+		 JsonTableParent *n = castNode(JsonTableParent, node);
+
+		 if (needcomma)
+			 appendStringInfoChar(context->buf, ',');
+
+		 appendStringInfoChar(context->buf, ' ');
+		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
+		 get_const_expr(n->path, context, -1);
+		 get_json_table_columns(tf, n, context, showimplicit);
+	}
+}
+
+/*
+ * get_json_table_columns - Parse back JSON_TABLE columns
+ */
+static void
+get_json_table_columns(TableFunc *tf, JsonTableParent *node,
+					   deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	ListCell   *lc_colname;
+	ListCell   *lc_coltype;
+	ListCell   *lc_coltypmod;
+	ListCell   *lc_colvarexpr;
+	int			colnum = 0;
+
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "COLUMNS (", 0, 0, 0);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	forfour(lc_colname, tf->colnames,
+			lc_coltype, tf->coltypes,
+			lc_coltypmod, tf->coltypmods,
+			lc_colvarexpr, tf->colvalexprs)
+	{
+		char	   *colname = strVal(lfirst(lc_colname));
+		JsonExpr   *colexpr;
+		Oid			typid;
+		int32		typmod;
+		bool		ordinality;
+		JsonBehaviorType default_behavior;
+
+		typid = lfirst_oid(lc_coltype);
+		typmod = lfirst_int(lc_coltypmod);
+		colexpr = castNode(JsonExpr, lfirst(lc_colvarexpr));
+
+		if (colnum < node->colMin)
+		{
+			colnum++;
+			continue;
+		}
+
+		if (colnum > node->colMax)
+			break;
+
+		if (colnum > node->colMin)
+			appendStringInfoString(buf, ", ");
+
+		colnum++;
+
+		ordinality = !colexpr;
+
+		appendContextKeyword(context, "", 0, 0, 0);
+
+		appendStringInfo(buf, "%s %s", quote_identifier(colname),
+						 ordinality ? "FOR ORDINALITY" :
+						 format_type_with_typemod(typid, typmod));
+		if (ordinality)
+			continue;
+
+		if (colexpr->op == IS_JSON_EXISTS)
+		{
+			appendStringInfoString(buf, " EXISTS");
+			default_behavior = JSON_BEHAVIOR_FALSE;
+		}
+		else
+		{
+			if (colexpr->op == IS_JSON_QUERY)
+			{
+				char		typcategory;
+				bool		typispreferred;
+
+				get_type_category_preferred(typid, &typcategory, &typispreferred);
+
+				if (typcategory == TYPCATEGORY_STRING)
+					appendStringInfoString(buf,
+										   colexpr->format->format_type == JS_FORMAT_JSONB ?
+										   " FORMAT JSONB" : " FORMAT JSON");
+			}
+
+			default_behavior = JSON_BEHAVIOR_NULL;
+		}
+
+		if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
+			default_behavior = JSON_BEHAVIOR_ERROR;
+
+		appendStringInfoString(buf, " PATH ");
+
+		get_json_path_spec(colexpr->path_spec, context, showimplicit);
+
+		get_json_expr_options(colexpr, context, default_behavior);
+	}
+
+	if (node->child)
+		get_json_table_nested_columns(tf, node->child, context, showimplicit,
+									  node->colMax >= node->colMin);
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_json_table			- Parse back a JSON_TABLE function
+ * ----------
+ */
+static void
+get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	StringInfo	buf = context->buf;
+	JsonExpr   *jexpr = castNode(JsonExpr, tf->docexpr);
+	JsonTableParent *root = castNode(JsonTableParent, tf->plan);
+
+	appendStringInfoString(buf, "JSON_TABLE(");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel += PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, "", 0, 0, 0);
+
+	get_rule_expr(jexpr->formatted_expr, context, showimplicit);
+
+	appendStringInfoString(buf, ", ");
+
+	get_const_expr(root->path, context, -1);
+
+	if (jexpr->passing_values)
+	{
+		ListCell   *lc1, *lc2;
+		bool		needcomma = false;
+
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PASSING ", 0, 0, 0);
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel += PRETTYINDENT_VAR;
+
+		forboth(lc1, jexpr->passing_names,
+				lc2, jexpr->passing_values)
+		{
+			if (needcomma)
+				appendStringInfoString(buf, ", ");
+			needcomma = true;
+
+			appendContextKeyword(context, "", 0, 0, 0);
+
+			get_rule_expr((Node *) lfirst(lc2), context, false);
+			appendStringInfo(buf, " AS %s",
+							 quote_identifier((lfirst_node(String, lc1))->sval)
+				);
+		}
+
+		if (PRETTY_INDENT(context))
+			context->indentLevel -= PRETTYINDENT_VAR;
+	}
+
+	get_json_table_columns(tf, root, context, showimplicit);
+
+	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+		get_json_behavior(jexpr->on_error, context, "ERROR");
+
+	if (PRETTY_INDENT(context))
+		context->indentLevel -= PRETTYINDENT_VAR;
+
+	appendContextKeyword(context, ")", 0, 0, 0);
+}
+
+/* ----------
+ * get_tablefunc			- Parse back a table function
+ * ----------
+ */
+static void
+get_tablefunc(TableFunc *tf, deparse_context *context, bool showimplicit)
+{
+	/* XMLTABLE and JSON_TABLE are the only existing implementations.  */
+
+	if (tf->functype == TFT_XMLTABLE)
+		get_xmltable(tf, context, showimplicit);
+	else if (tf->functype == TFT_JSON_TABLE)
+		get_json_table(tf, context, showimplicit);
+}
+
 /* ----------
  * get_from_clause			- Parse back a FROM clause
  *
diff --git a/src/backend/utils/misc/queryjumble.c b/src/backend/utils/misc/queryjumble.c
index 7120836c70..2ffa014618 100644
--- a/src/backend/utils/misc/queryjumble.c
+++ b/src/backend/utils/misc/queryjumble.c
@@ -878,9 +878,11 @@ JumbleExpr(JumbleState *jstate, Node *node)
 			{
 				TableFunc  *tablefunc = (TableFunc *) node;
 
+				APP_JUMB(tablefunc->functype);
 				JumbleExpr(jstate, tablefunc->docexpr);
 				JumbleExpr(jstate, tablefunc->rowexpr);
 				JumbleExpr(jstate, (Node *) tablefunc->colexprs);
+				JumbleExpr(jstate, (Node *) tablefunc->colvalexprs);
 			}
 			break;
 		case T_TableSampleClause:
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 9ce8df17e5..9df70e6f06 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -850,6 +850,10 @@ extern Datum ExecPrepareJsonItemCoercion(struct JsonbValue *item,
 										 struct JsonCoercionState **pjcstate);
 extern bool ExecEvalJsonNeedsSubTransaction(JsonExpr *jsexpr,
 											struct JsonCoercionsState *);
+extern Datum ExecEvalExprPassingCaseValue(ExprState *estate,
+										  ExprContext *econtext, bool *isnull,
+										  Datum caseval_datum,
+										  bool caseval_isnull);
 
 extern void ExecAggInitGroup(AggState *aggstate, AggStatePerTrans pertrans, AggStatePerGroup pergroup,
 							 ExprContext *aggcontext);
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 37deb134b9..58b61cf3ab 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -211,6 +211,8 @@ typedef enum NodeTag
 	T_JsonExpr,
 	T_JsonCoercion,
 	T_JsonItemCoercions,
+	T_JsonTableParent,
+	T_JsonTableSibling,
 
 	/*
 	 * TAGS FOR EXPRESSION STATE NODES (execnodes.h)
@@ -509,6 +511,8 @@ typedef enum NodeTag
 	T_JsonArrayAgg,
 	T_JsonFuncExpr,
 	T_JsonIsPredicate,
+	T_JsonTable,
+	T_JsonTableColumn,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 60cceb9bdc..1657ce4746 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1566,6 +1566,19 @@ typedef enum JsonQuotes
 	JS_QUOTES_OMIT				/* OMIT QUOTES */
 } JsonQuotes;
 
+/*
+ * JsonTableColumnType -
+ *		enumeration of JSON_TABLE column types
+ */
+typedef enum
+{
+	JTC_FOR_ORDINALITY,
+	JTC_REGULAR,
+	JTC_EXISTS,
+	JTC_FORMATTED,
+	JTC_NESTED,
+} JsonTableColumnType;
+
 /*
  * JsonPathSpec -
  *		representation of JSON path constant
@@ -1625,6 +1638,41 @@ typedef struct JsonFuncExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonFuncExpr;
 
+/*
+ * JsonTableColumn -
+ *		untransformed representation of JSON_TABLE column
+ */
+typedef struct JsonTableColumn
+{
+	NodeTag		type;
+	JsonTableColumnType coltype;	/* column type */
+	char	   *name;				/* column name */
+	TypeName   *typeName;			/* column type name */
+	JsonPathSpec pathspec;			/* path specification, if any */
+	JsonFormat *format;				/* JSON format clause, if specified */
+	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
+	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
+	List	   *columns;			/* nested columns */
+	JsonBehavior *on_empty;			/* ON EMPTY behavior */
+	JsonBehavior *on_error;			/* ON ERROR behavior */
+	int			location;			/* token location, or -1 if unknown */
+} JsonTableColumn;
+
+/*
+ * JsonTable -
+ *		untransformed representation of JSON_TABLE
+ */
+typedef struct JsonTable
+{
+	NodeTag		type;
+	JsonCommon *common;					/* common JSON path syntax fields */
+	List	   *columns;				/* list of JsonTableColumn */
+	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
+	Alias	   *alias;					/* table alias in FROM clause */
+	bool		lateral;				/* does it have LATERAL prefix? */
+	int			location;				/* token location, or -1 if unknown */
+} JsonTable;
+
 /*
  * JsonKeyValue -
  *		untransformed representation of JSON object key-value pair for
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index cc28c20c0e..47853cd763 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -73,8 +73,14 @@ typedef struct RangeVar
 	int			location;		/* token location, or -1 if unknown */
 } RangeVar;
 
+typedef enum TableFuncType
+{
+	TFT_XMLTABLE,
+	TFT_JSON_TABLE
+} TableFuncType;
+
 /*
- * TableFunc - node for a table function, such as XMLTABLE.
+ * TableFunc - node for a table function, such as XMLTABLE or JSON_TABLE.
  *
  * Entries in the ns_names list are either String nodes containing
  * literal namespace names, or NULL pointers to represent DEFAULT.
@@ -82,6 +88,7 @@ typedef struct RangeVar
 typedef struct TableFunc
 {
 	NodeTag		type;
+	TableFuncType functype;		/* XMLTABLE or JSON_TABLE */
 	List	   *ns_uris;		/* list of namespace URI expressions */
 	List	   *ns_names;		/* list of namespace names or NULL */
 	Node	   *docexpr;		/* input document expression */
@@ -92,7 +99,9 @@ typedef struct TableFunc
 	List	   *colcollations;	/* OID list of column collation OIDs */
 	List	   *colexprs;		/* list of column filter expressions */
 	List	   *coldefexprs;	/* list of column default expressions */
+	List	   *colvalexprs;	/* list of column value expressions */
 	Bitmapset  *notnulls;		/* nullability flag for each output column */
+	Node	   *plan;			/* JSON_TABLE plan */
 	int			ordinalitycol;	/* counts from 0; -1 if none specified */
 	int			location;		/* token location, or -1 if unknown */
 } TableFunc;
@@ -1241,7 +1250,8 @@ typedef enum JsonExprOp
 {
 	IS_JSON_VALUE,				/* JSON_VALUE() */
 	IS_JSON_QUERY,				/* JSON_QUERY() */
-	IS_JSON_EXISTS				/* JSON_EXISTS() */
+	IS_JSON_EXISTS,				/* JSON_EXISTS() */
+	IS_JSON_TABLE				/* JSON_TABLE() */
 } JsonExprOp;
 
 /*
@@ -1455,6 +1465,31 @@ typedef struct JsonExpr
 	int			location;		/* token location, or -1 if unknown */
 } JsonExpr;
 
+/*
+ * JsonTableParent -
+ *		transformed representation of parent JSON_TABLE plan node
+ */
+typedef struct JsonTableParent
+{
+	NodeTag		type;
+	Const	   *path;		/* jsonpath constant */
+	Node	   *child;		/* nested columns, if any */
+	int			colMin;		/* min column index in the resulting column list */
+	int			colMax;		/* max column index in the resulting column list */
+	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
+} JsonTableParent;
+
+/*
+ * JsonTableSibling -
+ *		transformed representation of joined sibling JSON_TABLE plan node
+ */
+typedef struct JsonTableSibling
+{
+	NodeTag		type;
+	Node	   *larg;		/* left join node */
+	Node	   *rarg;		/* right join node */
+} JsonTableSibling;
+
 /* ----------------
  * NullTest
  *
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index ab3d8e0b52..c7365706a3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -241,6 +241,7 @@ PG_KEYWORD("json_objectagg", JSON_OBJECTAGG, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_query", JSON_QUERY, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_scalar", JSON_SCALAR, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_serialize", JSON_SERIALIZE, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("json_table", JSON_TABLE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("json_value", JSON_VALUE, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("keep", KEEP, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("key", KEY, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -281,6 +282,7 @@ PG_KEYWORD("names", NAMES, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("national", NATIONAL, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("natural", NATURAL, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nchar", NCHAR, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("nested", NESTED, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("new", NEW, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("next", NEXT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("nfc", NFC, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -330,6 +332,7 @@ PG_KEYWORD("partial", PARTIAL, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("partition", PARTITION, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/parser/parse_clause.h b/src/include/parser/parse_clause.h
index 2495c30034..e86b002392 100644
--- a/src/include/parser/parse_clause.h
+++ b/src/include/parser/parse_clause.h
@@ -51,4 +51,7 @@ extern List *addTargetToSortList(ParseState *pstate, TargetEntry *tle,
 extern Index assignSortGroupRef(TargetEntry *tle, List *tlist);
 extern bool targetIsInSortList(TargetEntry *tle, Oid sortop, List *sortList);
 
+/* functions in parse_jsontable.c */
+extern ParseNamespaceItem *transformJsonTable(ParseState *pstate, JsonTable *jt);
+
 #endif							/* PARSE_CLAUSE_H */
diff --git a/src/include/utils/jsonpath.h b/src/include/utils/jsonpath.h
index 98a61d7f72..1897ddffa6 100644
--- a/src/include/utils/jsonpath.h
+++ b/src/include/utils/jsonpath.h
@@ -15,6 +15,7 @@
 #define JSONPATH_H
 
 #include "fmgr.h"
+#include "executor/tablefunc.h"
 #include "nodes/pg_list.h"
 #include "nodes/primnodes.h"
 #include "utils/jsonb.h"
@@ -263,6 +264,7 @@ typedef struct JsonPathVariableEvalContext
 	int32		typmod;
 	struct ExprContext *econtext;
 	struct ExprState  *estate;
+	MemoryContext mcxt;		/* memory context for cached value */
 	Datum		value;
 	bool		isnull;
 	bool		evaluated;
@@ -281,4 +283,6 @@ extern JsonbValue *JsonPathValue(Datum jb, JsonPath *jp, bool *empty,
 extern int EvalJsonPathVar(void *vars, char *varName, int varNameLen,
 						   JsonbValue *val, JsonbValue *baseObject);
 
+extern const TableFuncRoutine JsonbTableRoutine;
+
 #endif
diff --git a/src/test/regress/expected/json_sqljson.out b/src/test/regress/expected/json_sqljson.out
index bb62634314..5c4dfa5f7c 100644
--- a/src/test/regress/expected/json_sqljson.out
+++ b/src/test/regress/expected/json_sqljson.out
@@ -13,3 +13,9 @@ SELECT JSON_QUERY(NULL FORMAT JSON, '$');
 ERROR:  JSON_QUERY() is not yet implemented for json type
 LINE 1: SELECT JSON_QUERY(NULL FORMAT JSON, '$');
                ^
+-- JSON_TABLE
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
+ERROR:  JSON_TABLE() is not yet implemented for json type
+LINE 1: SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo ...
+                                 ^
+HINT:  Try casting the argument to jsonb
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 1126d7caf5..c766a441be 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1016,3 +1016,565 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.dateti
 ERROR:  functions in index expression must be marked IMMUTABLE
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+-- JSON_TABLE
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+ERROR:  syntax error at or near "("
+LINE 1: SELECT JSON_TABLE('[]', '$');
+                         ^
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+ERROR:  syntax error at or near ")"
+LINE 1: SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+                                                    ^
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+ foo 
+-----
+(0 rows)
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+ item | foo 
+------+-----
+  123 |    
+(1 row)
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+                                          js                                           | id | id2 | int |  text   | char(4) | bool | numeric | domain  |      js      |      jb      |     jst      | jsc  | jsv  |     jsb      |     jsbq     | aaa | aaa1 | exists1 | exists2 | exists3 | exists4 |     js2      |     jsb2w      |    jsb2q     | ia | ta | jba 
+---------------------------------------------------------------------------------------+----+-----+-----+---------+---------+------+---------+---------+--------------+--------------+--------------+------+------+--------------+--------------+-----+------+---------+---------+---------+---------+--------------+----------------+--------------+----+----+-----
+ 1                                                                                     |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ []                                                                                    |    |     |     |         |         |      |         |         |              |              |              |      |      |              |              |     |      |         |         |         |         |              |                |              |    |    | 
+ {}                                                                                    |  1 |   1 |     |         |         |      |         |         | {}           | {}           | {}           | {}   | {}   | {}           | {}           |     |      | f       |       0 |         | false   | {}           | [{}]           | {}           |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  1 |   1 |   1 | 1       | 1       |      |       1 | 1       | 1            | 1            | 1            | 1    | 1    | 1            | 1            |     |      | f       |       0 |         | false   | 1            | [1]            | 1            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  2 |   2 |   1 | 1.23    | 1.23    |      |    1.23 | 1.23    | 1.23         | 1.23         | 1.23         | 1.23 | 1.23 | 1.23         | 1.23         |     |      | f       |       0 |         | false   | 1.23         | [1.23]         | 1.23         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  3 |   3 |   2 | 2       | 2       |      |       2 | 2       | "2"          | "2"          | "2"          | "2"  | "2"  | "2"          | 2            |     |      | f       |       0 |         | false   | "2"          | ["2"]          | 2            |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  4 |   4 |     | aaaaaaa | aaaa    |      |         | aaaaaaa | "aaaaaaa"    | "aaaaaaa"    | "aaaaaaa"    | "aaa | "aaa | "aaaaaaa"    |              |     |      | f       |       0 |         | false   | "aaaaaaa"    | ["aaaaaaa"]    |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  5 |   5 |     | foo     | foo     |      |         |         | "foo"        | "foo"        | "foo"        | "foo | "foo | "foo"        |              |     |      | f       |       0 |         | false   | "foo"        | ["foo"]        |              |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  6 |   6 |     |         |         |      |         |         | null         | null         | null         | null | null | null         | null         |     |      | f       |       0 |         | false   | null         | [null]         | null         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  7 |   7 |   0 | false   | fals    | f    |         | false   | false        | false        | false        | fals | fals | false        | false        |     |      | f       |       0 |         | false   | false        | [false]        | false        |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  8 |   8 |   1 | true    | true    | t    |         | true    | true         | true         | true         | true | true | true         | true         |     |      | f       |       0 |         | false   | true         | [true]         | true         |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] |  9 |   9 |     |         |         |      |         |         | {"aaa": 123} | {"aaa": 123} | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123} | 123 |  123 | t       |       1 |       1 | true    | {"aaa": 123} | [{"aaa": 123}] | {"aaa": 123} |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 |  10 |     | [1,2]   | [1,2    |      |         | [1,2]   | "[1,2]"      | "[1,2]"      | "[1,2]"      | "[1, | "[1, | "[1,2]"      | [1, 2]       |     |      | f       |       0 |         | false   | "[1,2]"      | ["[1,2]"]      | [1, 2]       |    |    | 
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 |  11 |     | "str"   | "str    |      |         | "str"   | "\"str\""    | "\"str\""    | "\"str\""    | "\"s | "\"s | "\"str\""    | "str"        |     |      | f       |       0 |         | false   | "\"str\""    | ["\"str\""]    | "str"        |    |    | 
+(14 rows)
+
+-- JSON_TABLE: Test backward parsing
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+\sv jsonb_table_view
+CREATE OR REPLACE VIEW public.jsonb_table_view AS
+ SELECT "json_table".id,
+    "json_table".id2,
+    "json_table"."int",
+    "json_table".text,
+    "json_table"."char(4)",
+    "json_table".bool,
+    "json_table"."numeric",
+    "json_table".domain,
+    "json_table".js,
+    "json_table".jb,
+    "json_table".jst,
+    "json_table".jsc,
+    "json_table".jsv,
+    "json_table".jsb,
+    "json_table".jsbq,
+    "json_table".aaa,
+    "json_table".aaa1,
+    "json_table".exists1,
+    "json_table".exists2,
+    "json_table".exists3,
+    "json_table".js2,
+    "json_table".jsb2w,
+    "json_table".jsb2q,
+    "json_table".ia,
+    "json_table".ta,
+    "json_table".jba,
+    "json_table".a1,
+    "json_table".b1,
+    "json_table".a11,
+    "json_table".a21,
+    "json_table".a22
+   FROM JSON_TABLE(
+            'null'::jsonb, '$[*]'
+            PASSING
+                1 + 2 AS a,
+                '"foo"'::json AS "b c"
+            COLUMNS (
+                id FOR ORDINALITY,
+                id2 FOR ORDINALITY,
+                "int" integer PATH '$',
+                text text PATH '$',
+                "char(4)" character(4) PATH '$',
+                bool boolean PATH '$',
+                "numeric" numeric PATH '$',
+                domain jsonb_test_domain PATH '$',
+                js json PATH '$',
+                jb jsonb PATH '$',
+                jst text FORMAT JSON PATH '$',
+                jsc character(4) FORMAT JSON PATH '$',
+                jsv character varying(4) FORMAT JSON PATH '$',
+                jsb jsonb PATH '$',
+                jsbq jsonb PATH '$' OMIT QUOTES,
+                aaa integer PATH '$."aaa"',
+                aaa1 integer PATH '$."aaa"',
+                exists1 boolean EXISTS PATH '$."aaa"',
+                exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR,
+                exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR,
+                js2 json PATH '$',
+                jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER,
+                jsb2q jsonb PATH '$' OMIT QUOTES,
+                ia integer[] PATH '$',
+                ta text[] PATH '$',
+                jba jsonb[] PATH '$',
+                NESTED PATH '$[1]'
+                COLUMNS (
+                    a1 integer PATH '$."a1"',
+                    b1 text PATH '$."b1"',
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a11 text PATH '$."a11"'
+                    )
+                ),
+                NESTED PATH '$[2]'
+                COLUMNS (
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a21 text PATH '$."a21"'
+                    ),
+                    NESTED PATH '$[*]'
+                    COLUMNS (
+                        a22 text PATH '$."a22"'
+                    )
+                )
+            )
+        )
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table"
+   Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+(3 rows)
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+  js   | a 
+-------+---
+ 1     | 1
+ "err" |  
+(2 rows)
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+ERROR:  invalid input syntax for type integer: "err"
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+ a 
+---
+  
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  jsonpath member accessor can only be applied to an object
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+ERROR:  no SQL/JSON item
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 2
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+ a 
+---
+ 1
+(1 row)
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+ a 
+---
+ 0
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to smallint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to bigint
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to real
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+  a  
+-----
+ fal
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to json
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
+                                                             ^
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+ERROR:  cannot cast type boolean to jsonb
+LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
+                                                             ^
+-- JSON_TABLE: nested paths and plans
+-- Should fail (column names must be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: b
+HINT:  JSON_TABLE column names must be distinct from one another
+-- JSON_TABLE: plan execution
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+ x | y |      y       | z 
+---+---+--------------+---
+ 2 | 1 | [1, 2, 3]    | 1
+ 2 | 1 | [1, 2, 3]    | 2
+ 2 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [1, 2, 3]    | 1
+ 3 | 1 | [1, 2, 3]    | 2
+ 3 | 1 | [1, 2, 3]    | 3
+ 3 | 1 | [2, 3, 4, 5] | 2
+ 3 | 1 | [2, 3, 4, 5] | 3
+ 3 | 1 | [2, 3, 4, 5] | 4
+ 3 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [1, 2, 3]    | 1
+ 4 | 1 | [1, 2, 3]    | 2
+ 4 | 1 | [1, 2, 3]    | 3
+ 4 | 1 | [2, 3, 4, 5] | 2
+ 4 | 1 | [2, 3, 4, 5] | 3
+ 4 | 1 | [2, 3, 4, 5] | 4
+ 4 | 1 | [2, 3, 4, 5] | 5
+ 4 | 1 | [3, 4, 5, 6] | 3
+ 4 | 1 | [3, 4, 5, 6] | 4
+ 4 | 1 | [3, 4, 5, 6] | 5
+ 4 | 1 | [3, 4, 5, 6] | 6
+ 2 | 2 | [1, 2, 3]    | 2
+ 2 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [1, 2, 3]    | 2
+ 3 | 2 | [1, 2, 3]    | 3
+ 3 | 2 | [2, 3, 4, 5] | 2
+ 3 | 2 | [2, 3, 4, 5] | 3
+ 3 | 2 | [2, 3, 4, 5] | 4
+ 3 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [1, 2, 3]    | 2
+ 4 | 2 | [1, 2, 3]    | 3
+ 4 | 2 | [2, 3, 4, 5] | 2
+ 4 | 2 | [2, 3, 4, 5] | 3
+ 4 | 2 | [2, 3, 4, 5] | 4
+ 4 | 2 | [2, 3, 4, 5] | 5
+ 4 | 2 | [3, 4, 5, 6] | 3
+ 4 | 2 | [3, 4, 5, 6] | 4
+ 4 | 2 | [3, 4, 5, 6] | 5
+ 4 | 2 | [3, 4, 5, 6] | 6
+ 2 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [1, 2, 3]    | 3
+ 3 | 3 | [2, 3, 4, 5] | 3
+ 3 | 3 | [2, 3, 4, 5] | 4
+ 3 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [1, 2, 3]    | 3
+ 4 | 3 | [2, 3, 4, 5] | 3
+ 4 | 3 | [2, 3, 4, 5] | 4
+ 4 | 3 | [2, 3, 4, 5] | 5
+ 4 | 3 | [3, 4, 5, 6] | 3
+ 4 | 3 | [3, 4, 5, 6] | 4
+ 4 | 3 | [3, 4, 5, 6] | 5
+ 4 | 3 | [3, 4, 5, 6] | 6
+(52 rows)
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+ERROR:  could not find jsonpath variable "x"
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_exists 
+-------------
+ t
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_value 
+------------
+ 123
+(1 row)
+
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+ json_value 
+------------
+ foo
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+ json_query 
+------------
+ 123
+(1 row)
+
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+ json_query 
+------------
+ [123]
+(1 row)
+
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+ERROR:  syntax error, unexpected IDENT_P at or near " " of jsonpath input
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+ERROR:  only string constants supported in JSON_TABLE path specification
+LINE 1: SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || '...
+                                                     ^
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+                 QUERY PLAN                  
+---------------------------------------------
+ Aggregate
+   ->  Seq Scan on test_parallel_jsonb_value
+(2 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+                            QUERY PLAN                            
+------------------------------------------------------------------
+ Finalize Aggregate
+   ->  Gather
+         Workers Planned: 2
+         ->  Partial Aggregate
+               ->  Parallel Seq Scan on test_parallel_jsonb_value
+(5 rows)
+
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+     sum      
+--------------
+ 500000500000
+(1 row)
+
diff --git a/src/test/regress/sql/json_sqljson.sql b/src/test/regress/sql/json_sqljson.sql
index 4f30fa46b9..df4a430d88 100644
--- a/src/test/regress/sql/json_sqljson.sql
+++ b/src/test/regress/sql/json_sqljson.sql
@@ -9,3 +9,7 @@ SELECT JSON_VALUE(NULL FORMAT JSON, '$');
 -- JSON_QUERY
 
 SELECT JSON_QUERY(NULL FORMAT JSON, '$');
+
+-- JSON_TABLE
+
+SELECT * FROM JSON_TABLE(NULL FORMAT JSON, '$' COLUMNS (foo text));
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 00a067a06a..8b813a3c2e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -315,3 +315,287 @@ CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime()
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, 0 to $.a ? (@.datetime() == $x)]' PASSING '12:34'::time AS x));
 CREATE INDEX ON test_jsonb_mutability (JSON_QUERY(js, '$[1, $.a ? (@.datetime("HH:MI") == $x)]' PASSING '12:34'::time AS x));
 DROP TABLE test_jsonb_mutability;
+
+-- JSON_TABLE
+
+-- Should fail (JSON_TABLE can be used only in FROM clause)
+SELECT JSON_TABLE('[]', '$');
+
+-- Should fail (no columns)
+SELECT * FROM JSON_TABLE(NULL, '$' COLUMNS ());
+
+-- NULL => empty table
+SELECT * FROM JSON_TABLE(NULL::jsonb, '$' COLUMNS (foo int)) bar;
+
+--
+SELECT * FROM JSON_TABLE(jsonb '123', '$'
+	COLUMNS (item int PATH '$', foo int)) bar;
+
+-- JSON_TABLE: basic functionality
+CREATE DOMAIN jsonb_test_domain AS text CHECK (value <> 'foo');
+
+SELECT *
+FROM
+	(VALUES
+		('1'),
+		('[]'),
+		('{}'),
+		('[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""]')
+	) vals(js)
+	LEFT OUTER JOIN
+-- JSON_TABLE is implicitly lateral
+	JSON_TABLE(
+		vals.js::jsonb, 'lax $[*]'
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa',
+			exists3 int EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+			exists4 text EXISTS PATH 'strict $.aaa' FALSE ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$'
+		)
+	) jt
+	ON true;
+
+-- JSON_TABLE: Test backward parsing
+
+CREATE VIEW jsonb_table_view AS
+SELECT * FROM
+	JSON_TABLE(
+		jsonb 'null', 'lax $[*]' PASSING 1 + 2 AS a, json '"foo"' AS "b c"
+		COLUMNS (
+			id FOR ORDINALITY,
+			id2 FOR ORDINALITY, -- allowed additional ordinality columns
+			"int" int PATH '$',
+			"text" text PATH '$',
+			"char(4)" char(4) PATH '$',
+			"bool" bool PATH '$',
+			"numeric" numeric PATH '$',
+			"domain" jsonb_test_domain PATH '$',
+			js json PATH '$',
+			jb jsonb PATH '$',
+			jst text    FORMAT JSON  PATH '$',
+			jsc char(4) FORMAT JSON  PATH '$',
+			jsv varchar(4) FORMAT JSON  PATH '$',
+			jsb jsonb   FORMAT JSON PATH '$',
+			jsbq jsonb FORMAT JSON PATH '$' OMIT QUOTES,
+			aaa int, -- implicit path '$."aaa"',
+			aaa1 int PATH '$.aaa',
+			exists1 bool EXISTS PATH '$.aaa',
+			exists2 int EXISTS PATH '$.aaa' TRUE ON ERROR,
+			exists3 text EXISTS PATH 'strict $.aaa' UNKNOWN ON ERROR,
+
+			js2 json PATH '$',
+			jsb2w jsonb PATH '$' WITH WRAPPER,
+			jsb2q jsonb PATH '$' OMIT QUOTES,
+			ia int[] PATH '$',
+			ta text[] PATH '$',
+			jba jsonb[] PATH '$',
+
+			NESTED PATH '$[1]' COLUMNS (
+				a1 int,
+				NESTED PATH '$[*]' COLUMNS (
+					a11 text
+				),
+				b1 text
+			),
+			NESTED PATH '$[2]' COLUMNS (
+				NESTED PATH '$[*]' COLUMNS (
+					a21 text
+				),
+				NESTED PATH '$[*]' COLUMNS (
+					a22 text
+				)
+			)
+		)
+	);
+
+\sv jsonb_table_view
+
+EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
+
+DROP VIEW jsonb_table_view;
+DROP DOMAIN jsonb_test_domain;
+
+-- JSON_TABLE: ON EMPTY/ON ERROR behavior
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js),
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$')) jt;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$') ERROR ON ERROR) jt
+		ON true;
+
+SELECT *
+FROM
+	(VALUES ('1'), ('"err"')) vals(js)
+		LEFT OUTER JOIN
+	JSON_TABLE(vals.js::jsonb, '$' COLUMNS (a int PATH '$' ERROR ON ERROR)) jt
+		ON true;
+
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH '$.a' ERROR ON EMPTY)) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'strict $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int PATH 'lax $.a' ERROR ON EMPTY) ERROR ON ERROR) jt;
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH '$'   DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
+
+-- JSON_TABLE: EXISTS PATH types
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+
+-- JSON_TABLE: nested paths and plans
+
+-- Should fail (column names must be distinct)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		a int,
+		b text,
+		a jsonb
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		b int,
+		NESTED PATH '$'
+		COLUMNS (
+			c int,
+			b text
+		)
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$'
+	COLUMNS (
+		NESTED PATH '$'
+		COLUMNS (
+			b int
+		),
+		NESTED PATH '$'
+		COLUMNS (
+			NESTED PATH '$'
+			COLUMNS (
+				c int,
+				b text
+			)
+		)
+	)
+) jt;
+
+-- JSON_TABLE: plan execution
+
+CREATE TEMP TABLE jsonb_table_test (js jsonb);
+
+INSERT INTO jsonb_table_test
+VALUES (
+	'[
+		{"a":  1,  "b": [], "c": []},
+		{"a":  2,  "b": [1, 2, 3], "c": [10, null, 20]},
+		{"a":  3,  "b": [1, 2], "c": []},
+		{"x": "4", "b": [1, 2], "c": 123}
+	 ]'
+);
+
+-- unspecified plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+	) jt;
+
+-- Should succeed (JSON arguments are passed to root and nested paths)
+SELECT *
+FROM
+	generate_series(1, 4) x,
+	generate_series(1, 3) y,
+	JSON_TABLE(jsonb
+		'[[1,2,3],[2,3,4,5],[3,4,5,6]]',
+		'strict $[*] ? (@[*] < $x)'
+		PASSING x AS x, y AS y
+		COLUMNS (
+			y text FORMAT JSON PATH '$',
+			NESTED PATH 'strict $[*] ? (@ >= $y)'
+			COLUMNS (
+				z int PATH '$'
+			)
+		)
+	) jt;
+
+-- Should fail (JSON arguments are not passed to column paths)
+SELECT *
+FROM JSON_TABLE(
+	jsonb '[1,2,3]',
+	'$[*] ? (@ < $x)'
+		PASSING 10 AS x
+		COLUMNS (y text FORMAT JSON PATH '$ ? (@ < $x)')
+	) jt;
+
+-- Extension: non-constant JSON path
+SELECT JSON_EXISTS(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_VALUE(jsonb '{"a": 123}', '$' || '.' || 'b' DEFAULT 'foo' ON EMPTY);
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a');
+SELECT JSON_QUERY(jsonb '{"a": 123}', '$' || '.' || 'a' WITH WRAPPER);
+-- Should fail (invalid path)
+SELECT JSON_QUERY(jsonb '{"a": 123}', 'error' || ' ' || 'error');
+-- Should fail (not supported)
+SELECT * FROM JSON_TABLE(jsonb '{"a": 123}', '$' || '.' || 'a' COLUMNS (foo int));
+
+-- Test parallel JSON_VALUE()
+CREATE TABLE test_parallel_jsonb_value AS
+SELECT i::text::jsonb AS js
+FROM generate_series(1, 1000000) i;
+
+-- Should be non-parallel due to subtransactions
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric)) FROM test_parallel_jsonb_value;
+
+-- Should be parallel
+EXPLAIN (COSTS OFF)
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
+SELECT sum(JSON_VALUE(js, '$' RETURNING numeric ERROR ON ERROR)) FROM test_parallel_jsonb_value;
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 85c808af90..cd7c2d95ff 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1236,6 +1236,14 @@ JsonPathParseResult
 JsonPathPredicateCallback
 JsonPathString
 JsonSemAction
+JsonTable
+JsonTableColumn
+JsonTableColumnType
+JsonTableContext
+JsonTableJoinState
+JsonTableParent
+JsonTableScanState
+JsonTableSibling
 JsonTokenType
 JsonTransformStringValuesAction
 JsonTypeCategory
@@ -2638,6 +2646,7 @@ TableFunc
 TableFuncRoutine
 TableFuncScan
 TableFuncScanState
+TableFuncType
 TableInfo
 TableLikeClause
 TableSampleClause
-- 
2.25.1

0003-JSON_TABLE-PLAN-DEFAULT-clause-v59.patchtext/x-patch; charset=UTF-8; name=0003-JSON_TABLE-PLAN-DEFAULT-clause-v59.patchDownload
From e975b64cb906691a05ac8211f04f13d9d06c28a3 Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:02:22 -0500
Subject: [PATCH 3/4] JSON_TABLE PLAN DEFAULT clause

---
 doc/src/sgml/func.sgml                      | 118 +++++++++++++++++---
 src/backend/nodes/copyfuncs.c               |   4 +
 src/backend/nodes/equalfuncs.c              |   3 +
 src/backend/nodes/outfuncs.c                |   3 +
 src/backend/nodes/readfuncs.c               |   3 +
 src/backend/parser/gram.y                   |  41 ++++++-
 src/backend/parser/parse_jsontable.c        |  13 ++-
 src/backend/utils/adt/jsonpath_exec.c       | 118 +++++++++++++++-----
 src/backend/utils/adt/ruleutils.c           |   9 ++
 src/include/nodes/parsenodes.h              |  13 +++
 src/include/nodes/primnodes.h               |   3 +
 src/include/parser/kwlist.h                 |   1 +
 src/test/regress/expected/jsonb_sqljson.out | 118 ++++++++++++++++++++
 src/test/regress/sql/jsonb_sqljson.sql      |  65 +++++++++++
 src/tools/pgindent/typedefs.list            |   1 +
 15 files changed, 460 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index a256f8123f..0a6c72571b 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19315,6 +19315,10 @@ FROM
 JSON_TABLE (
   <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
+  <optional>
+    PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
+                 | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
+  </optional>
 )
 <phrase>
 where <replaceable class="parameter">json_table_column</replaceable> is:
@@ -19376,7 +19380,8 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       The rows produced by <function>JSON_TABLE</function> are laterally
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
-      data.
+      data. Optionally, you can specify how to join the columns returned
+      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
      </para>
 
      <para>
@@ -19389,22 +19394,6 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       the resulting rows are joined to the parent row.
      </para>
 
-     <para>
-      Columns with parent/child relationship are joined using
-      <literal>LEFT OUTER JOIN</literal>, so that the parent row
-      is always included into the output even if it does not have any child rows
-      after joining the data returned by <literal>NESTED PATH</literal>,
-      with NULL values inserted into the child columns if the corresponding
-      values are missing.
-     </para>
-
-     <para>
-      Sibling columns are joined using
-      <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
-      rows are included into the output, with NULL values inserted
-      into both child and parent columns for all missing values.
-     </para>
-
     </sect5>
     <sect5>
      <title>Parameters</title>
@@ -19576,6 +19565,10 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
      <function>JSON_TABLE</function> expressions in an SQL statement.
     </para>
 
+    <para>
+     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
+    </para>
     </listitem>
    </varlistentry>
 
@@ -19598,8 +19591,99 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+      clauses to the constructed view. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all
+      columns at once.
+     </para>
+
+    <para>
+     To join columns with parent/child relationship, you can use:
+    </para>
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>INNER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>INNER JOIN</literal>, so that the parent row
+     is omitted from the output if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>OUTER</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
+     is always included into the output even if it does not have any child rows
+     after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
+     inserted into the child columns if the corresponding
+     values are missing.
+    </para>
+    <para>
+     This is the default option for joining columns with parent/child relationship.
+    </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+
+     <para>
+     To join sibling columns, you can use:
+    </para>
+
+  <variablelist>
+   <varlistentry>
+    <term>
+     <literal>UNION</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>FULL OUTER JOIN ON FALSE</literal>, so that both parent and child
+     rows are included into the output, with NULL values inserted
+     into both child and parent columns for all missing values.
+    </para>
+    <para>
+     This is the default option for joining sibling columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>CROSS</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Use <literal>CROSS JOIN</literal>, so that the output includes 
+     a row for every possible combination of rows from the left-hand
+     and the right-hand columns.
+    </para>
+    </listitem>
+   </varlistentry>
+
   </variablelist>
 
+    </listitem>
+   </varlistentry>
+  </variablelist>
     </sect5>
 
     <sect5>
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 5c72986017..617cb9aad8 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2697,6 +2697,7 @@ _copyJsonTable(const JsonTable *from)
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
+	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2735,6 +2736,8 @@ _copyJsonTableParent(const JsonTableParent *from)
 
 	COPY_NODE_FIELD(path);
 	COPY_NODE_FIELD(child);
+	COPY_SCALAR_FIELD(outerJoin);
+	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -2751,6 +2754,7 @@ _copyJsonTableSibling(const JsonTableSibling *from)
 
 	COPY_NODE_FIELD(larg);
 	COPY_NODE_FIELD(rarg);
+	COPY_SCALAR_FIELD(cross);
 
 	return newnode;
 }
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index ee98f916d7..59cb8e58c7 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -182,6 +182,8 @@ _equalJsonTableParent(const JsonTableParent *a, const JsonTableParent *b)
 {
 	COMPARE_NODE_FIELD(path);
 	COMPARE_NODE_FIELD(child);
+	COMPARE_SCALAR_FIELD(outerJoin);
+	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
@@ -193,6 +195,7 @@ _equalJsonTableSibling(const JsonTableSibling *a, const JsonTableSibling *b)
 {
 	COMPARE_NODE_FIELD(larg);
 	COMPARE_NODE_FIELD(rarg);
+	COMPARE_SCALAR_FIELD(cross);
 
 	return true;
 }
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index e5a725a636..da920f3d36 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1875,6 +1875,8 @@ _outJsonTableParent(StringInfo str, const JsonTableParent *node)
 
 	WRITE_NODE_FIELD(path);
 	WRITE_NODE_FIELD(child);
+	WRITE_BOOL_FIELD(outerJoin);
+	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
@@ -1886,6 +1888,7 @@ _outJsonTableSibling(StringInfo str, const JsonTableSibling *node)
 
 	WRITE_NODE_FIELD(larg);
 	WRITE_NODE_FIELD(rarg);
+	WRITE_BOOL_FIELD(cross);
 }
 
 /*****************************************************************************
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 3b63df6edc..4a9392647c 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1504,6 +1504,8 @@ _readJsonTableParent(void)
 
 	READ_NODE_FIELD(path);
 	READ_NODE_FIELD(child);
+	READ_BOOL_FIELD(outerJoin);
+	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
@@ -1517,6 +1519,7 @@ _readJsonTableSibling(void)
 
 	READ_NODE_FIELD(larg);
 	READ_NODE_FIELD(rarg);
+	READ_BOOL_FIELD(cross);
 
 	READ_DONE();
 }
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 78f63d15b9..088edd68fa 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -692,6 +692,11 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
+					json_table_plan_clause_opt
+					json_table_default_plan
+					json_table_default_plan_choices
+					json_table_default_plan_inner_outer
+					json_table_default_plan_union_cross
 					json_wrapper_clause_opt
 					json_wrapper_behavior
 					json_conditional_or_unconditional_opt
@@ -805,7 +810,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 	ORDER ORDINALITY OTHERS OUT_P OUTER_P
 	OVER OVERLAPS OVERLAY OVERRIDING OWNED OWNER
 
-	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLANS POLICY
+	PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PATH PLACING PLAN PLANS POLICY
 	POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
 	PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
 
@@ -15750,13 +15755,15 @@ json_table:
 			JSON_TABLE '('
 				json_api_common_syntax
 				json_table_columns_clause
+				json_table_plan_clause_opt
 				json_table_error_clause_opt
 			')'
 				{
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->on_error = $5;
+					n->join_type = $5;
+					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15893,6 +15900,34 @@ path_opt:
 			| /* EMPTY */							{ }
 		;
 
+json_table_plan_clause_opt:
+			json_table_default_plan					{ $$ = $1; }
+			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+		;
+
+json_table_default_plan:
+			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+		;
+
+json_table_default_plan_choices:
+			json_table_default_plan_inner_outer			{ $$ = $1 | JSTPJ_UNION; }
+			| json_table_default_plan_inner_outer ','
+			  json_table_default_plan_union_cross		{ $$ = $1 | $3; }
+			| json_table_default_plan_union_cross		{ $$ = $1 | JSTPJ_OUTER; }
+			| json_table_default_plan_union_cross ','
+			  json_table_default_plan_inner_outer		{ $$ = $1 | $3; }
+		;
+
+json_table_default_plan_inner_outer:
+			INNER_P										{ $$ = JSTPJ_INNER; }
+			| OUTER_P									{ $$ = JSTPJ_OUTER; }
+		;
+
+json_table_default_plan_union_cross:
+			UNION										{ $$ = JSTPJ_UNION; }
+			| CROSS										{ $$ = JSTPJ_CROSS; }
+		;
+
 json_returning_clause_opt:
 			RETURNING Typename
 				{
@@ -16771,6 +16806,7 @@ unreserved_keyword:
 			| PASSING
 			| PASSWORD
 			| PATH
+			| PLAN
 			| PLANS
 			| POLICY
 			| PRECEDING
@@ -17386,6 +17422,7 @@ bare_label_keyword:
 			| PASSWORD
 			| PATH
 			| PLACING
+			| PLAN
 			| PLANS
 			| POLICY
 			| POSITION
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index becadc4d3b..5f2d647d9b 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -172,12 +172,13 @@ transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
 }
 
 static Node *
-makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
+makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 {
 	JsonTableSibling *join = makeNode(JsonTableSibling);
 
 	join->larg = lnode;
 	join->rarg = rnode;
+	join->cross = cross;
 
 	return (Node *) join;
 }
@@ -185,7 +186,7 @@ makeJsonTableSiblingJoin(Node *lnode, Node *rnode)
 /*
  * Recursively transform child (nested) JSON_TABLE columns.
  *
- * Child columns are transformed into a binary tree of union-joined
+ * Child columns are transformed into a binary tree of union/cross-joined
  * JsonTableSiblings.
  */
 static Node *
@@ -193,8 +194,9 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 {
 	Node	   *res = NULL;
 	ListCell   *lc;
+	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
 
-	/* transform all nested columns into union join */
+	/* transform all nested columns into union/cros join */
 	foreach(lc, columns)
 	{
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
@@ -206,7 +208,7 @@ transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
 		node = transformNestedJsonTableColumn(cxt, jtc);
 
 		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(res, node) : node;
+		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
 	}
 
 	return res;
@@ -385,6 +387,9 @@ transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
 	/* transform recursively nested columns */
 	node->child = transformJsonTableChildColumns(cxt, columns);
 
+	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
+	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+
 	return node;
 }
 
diff --git a/src/backend/utils/adt/jsonpath_exec.c b/src/backend/utils/adt/jsonpath_exec.c
index c55b3aae02..ee9b5089b9 100644
--- a/src/backend/utils/adt/jsonpath_exec.c
+++ b/src/backend/utils/adt/jsonpath_exec.c
@@ -175,6 +175,7 @@ struct JsonTableScanState
 	Datum		current;
 	int			ordinal;
 	bool		currentIsNull;
+	bool		outerJoin;
 	bool		errorOnError;
 	bool		advanceNested;
 	bool		reset;
@@ -188,6 +189,7 @@ struct JsonTableJoinState
 		{
 			JsonTableJoinState *left;
 			JsonTableJoinState *right;
+			bool		cross;
 			bool		advanceRight;
 		}			join;
 		JsonTableScanState scan;
@@ -3166,6 +3168,7 @@ JsonTableInitScanState(JsonTableContext *cxt, JsonTableScanState *scan,
 	int			i;
 
 	scan->parent = parent;
+	scan->outerJoin = node->outerJoin;
 	scan->errorOnError = node->errorOnError;
 	scan->path = DatumGetJsonPathP(node->path->constvalue);
 	scan->args = args;
@@ -3192,6 +3195,7 @@ JsonTableInitPlanState(JsonTableContext *cxt, Node *plan,
 		JsonTableSibling *join = castNode(JsonTableSibling, plan);
 
 		state->is_join = true;
+		state->u.join.cross = join->cross;
 		state->u.join.left = JsonTableInitPlanState(cxt, join->larg, parent);
 		state->u.join.right = JsonTableInitPlanState(cxt, join->rarg, parent);
 	}
@@ -3328,8 +3332,26 @@ JsonTableSetDocument(TableFuncScanState *state, Datum value)
 	JsonTableResetContextItem(&cxt->root, value);
 }
 
+/* Recursively reset scan and its child nodes */
+static void
+JsonTableRescanRecursive(JsonTableJoinState *state)
+{
+	if (state->is_join)
+	{
+		JsonTableRescanRecursive(state->u.join.left);
+		JsonTableRescanRecursive(state->u.join.right);
+		state->u.join.advanceRight = false;
+	}
+	else
+	{
+		JsonTableRescan(&state->u.scan);
+		if (state->u.scan.nested)
+			JsonTableRescanRecursive(state->u.scan.nested);
+	}
+}
+
 /*
- * Fetch next row from a union joined scan.
+ * Fetch next row from a cross/union joined scan.
  *
  * Returns false at the end of a scan, true otherwise.
  */
@@ -3339,17 +3361,48 @@ JsonTableNextJoinRow(JsonTableJoinState *state)
 	if (!state->is_join)
 		return JsonTableNextRow(&state->u.scan);
 
-	if (!state->u.join.advanceRight)
+	if (state->u.join.advanceRight)
 	{
-		/* fetch next outer row */
-		if (JsonTableNextJoinRow(state->u.join.left))
+		/* fetch next inner row */
+		if (JsonTableNextJoinRow(state->u.join.right))
 			return true;
 
-		state->u.join.advanceRight = true;	/* next inner row */
+		/* inner rows are exhausted */
+		if (state->u.join.cross)
+			state->u.join.advanceRight = false;	/* next outer row */
+		else
+			return false;	/* end of scan */
+	}
+
+	while (!state->u.join.advanceRight)
+	{
+		/* fetch next outer row */
+		bool		left = JsonTableNextJoinRow(state->u.join.left);
+
+		if (state->u.join.cross)
+		{
+			if (!left)
+				return false;	/* end of scan */
+
+			JsonTableRescanRecursive(state->u.join.right);
+
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				continue;	/* next outer row */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+		else if (!left)
+		{
+			if (!JsonTableNextJoinRow(state->u.join.right))
+				return false;	/* end of scan */
+
+			state->u.join.advanceRight = true;	/* next inner row */
+		}
+
+		break;
 	}
 
-	/* fetch next inner row */
-	return JsonTableNextJoinRow(state->u.join.right);
+	return true;
 }
 
 /* Recursively set 'reset' flag of scan and its child nodes */
@@ -3373,16 +3426,13 @@ JsonTableJoinReset(JsonTableJoinState *state)
 }
 
 /*
- * Fetch next row from a simple scan with outer joined nested subscans.
+ * Fetch next row from a simple scan with outer/inner joined nested subscans.
  *
  * Returns false at the end of a scan, true otherwise.
  */
 static bool
 JsonTableNextRow(JsonTableScanState *scan)
 {
-	JsonbValue *jbv;
-	MemoryContext oldcxt;
-
 	/* reset context item if requested */
 	if (scan->reset)
 	{
@@ -3394,34 +3444,42 @@ JsonTableNextRow(JsonTableScanState *scan)
 	if (scan->advanceNested)
 	{
 		/* fetch next nested row */
-		if (JsonTableNextJoinRow(scan->nested))
-			return true;
+		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
 
-		scan->advanceNested = false;
+		if (scan->advanceNested)
+			return true;
 	}
 
-	/* fetch next row */
-	jbv = JsonValueListNext(&scan->found, &scan->iter);
-
-	if (!jbv)
+	for (;;)
 	{
-		scan->current = PointerGetDatum(NULL);
-		scan->currentIsNull = true;
-		return false;	/* end of scan */
-	}
+		/* fetch next row */
+		JsonbValue *jbv = JsonValueListNext(&scan->found, &scan->iter);
+		MemoryContext oldcxt;
 
-	/* set current row item */
-	oldcxt = MemoryContextSwitchTo(scan->mcxt);
-	scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
-	scan->currentIsNull = false;
-	MemoryContextSwitchTo(oldcxt);
+		if (!jbv)
+		{
+			scan->current = PointerGetDatum(NULL);
+			scan->currentIsNull = true;
+			return false;	/* end of scan */
+		}
 
-	scan->ordinal++;
+		/* set current row item */
+		oldcxt = MemoryContextSwitchTo(scan->mcxt);
+		scan->current = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+		scan->currentIsNull = false;
+		MemoryContextSwitchTo(oldcxt);
+
+		scan->ordinal++;
+
+		if (!scan->nested)
+			break;
 
-	if (scan->nested)
-	{
 		JsonTableJoinReset(scan->nested);
+
 		scan->advanceNested = JsonTableNextJoinRow(scan->nested);
+
+		if (scan->advanceNested || scan->outerJoin)
+			break;
 	}
 
 	return true;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 43d04644e1..46a492dc95 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11295,6 +11295,15 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
+	if (!root->outerJoin || !root->unionJoin)
+	{
+		appendStringInfoChar(buf, ' ');
+		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
+		appendStringInfo(buf, "(%s, %s)",
+						 root->outerJoin ? "OUTER" : "INNER",
+						 root->unionJoin ? "UNION" : "CROSS");
+	}
+
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 1657ce4746..57ea498e3c 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1658,6 +1658,18 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanJoinType -
+ *		flags for JSON_TABLE join types representation
+ */
+typedef enum JsonTablePlanJoinType
+{
+	JSTPJ_INNER = 0x01,
+	JSTPJ_OUTER = 0x02,
+	JSTPJ_CROSS = 0x04,
+	JSTPJ_UNION = 0x08,
+} JsonTablePlanJoinType;
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1667,6 +1679,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
+	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 47853cd763..098f4c96ab 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1474,6 +1474,8 @@ typedef struct JsonTableParent
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
 	Node	   *child;		/* nested columns, if any */
+	bool		outerJoin;	/* outer or inner join for nested columns? */
+	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
@@ -1488,6 +1490,7 @@ typedef struct JsonTableSibling
 	NodeTag		type;
 	Node	   *larg;		/* left join node */
 	Node	   *rarg;		/* right join node */
+	bool		cross;		/* cross or union join? */
 } JsonTableSibling;
 
 /* ----------------
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index c7365706a3..ac17889517 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -334,6 +334,7 @@ PG_KEYWORD("passing", PASSING, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("password", PASSWORD, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("path", PATH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("placing", PLACING, RESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("plan", PLAN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("plans", PLANS, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("policy", POLICY, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("position", POSITION, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index c766a441be..0d8c5d6add 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1420,6 +1420,124 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 8b813a3c2e..9ad1047485 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -547,6 +547,71 @@ from
 		)
 	) jt;
 
+-- default plan (outer, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, union)
+	) jt;
+
+-- default plan (inner, union)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (inner)
+	) jt;
+
+-- default plan (inner, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (cross, inner)
+	) jt;
+
+-- default plan (outer, cross)
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]'
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' columns ( b int path '$' ),
+			nested path 'strict $.c[*]' columns ( c int path '$' )
+		)
+		plan default (outer, cross)
+	) jt;
+
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index cd7c2d95ff..a8f8005941 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1242,6 +1242,7 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParent
+JsonTablePlanJoinType
 JsonTableScanState
 JsonTableSibling
 JsonTokenType
-- 
2.25.1

0004-JSON_TABLE-PLAN-clause-v59.patchtext/x-patch; charset=UTF-8; name=0004-JSON_TABLE-PLAN-clause-v59.patchDownload
From 2e12850f1233de8e07a5a58ed50335abd4572e0b Mon Sep 17 00:00:00 2001
From: Andrew Dunstan <andrew@dunslane.net>
Date: Sat, 5 Mar 2022 09:03:20 -0500
Subject: [PATCH 4/4] JSON_TABLE PLAN clause

---
 doc/src/sgml/func.sgml                      |  97 +++-
 src/backend/nodes/copyfuncs.c               |  26 +-
 src/backend/nodes/equalfuncs.c              |   2 +-
 src/backend/nodes/makefuncs.c               |  19 +
 src/backend/nodes/outfuncs.c                |   2 +-
 src/backend/nodes/readfuncs.c               |   2 +-
 src/backend/parser/gram.y                   | 101 +++-
 src/backend/parser/parse_jsontable.c        | 324 +++++++++++--
 src/backend/utils/adt/ruleutils.c           |  57 ++-
 src/include/nodes/makefuncs.h               |   2 +
 src/include/nodes/nodes.h                   |   1 +
 src/include/nodes/parsenodes.h              |  31 +-
 src/include/nodes/primnodes.h               |   2 +-
 src/test/regress/expected/jsonb_sqljson.out | 506 ++++++++++++++++++--
 src/test/regress/sql/jsonb_sqljson.sql      | 355 ++++++++++++--
 src/tools/pgindent/typedefs.list            |   2 +
 16 files changed, 1389 insertions(+), 140 deletions(-)

diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 0a6c72571b..c3eb2803c0 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -19313,9 +19313,10 @@ FROM
 
 <synopsis>
 JSON_TABLE (
-  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
+  <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
   COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
   <optional>
+    PLAN ( <replaceable class="parameter">json_table_plan</replaceable> ) |
     PLAN DEFAULT ( { INNER | OUTER } <optional> , { CROSS | UNION } </optional>
                  | { CROSS | UNION } <optional> , { INNER | OUTER } </optional> )
   </optional>
@@ -19339,6 +19340,16 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
   | NESTED PATH <replaceable>json_path_specification</replaceable> <optional> AS <replaceable>path_name</replaceable> </optional>
         COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
   | <replaceable>name</replaceable> FOR ORDINALITY
+<phrase>
+<replaceable>json_table_plan</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> <optional> { OUTER | INNER } <replaceable>json_table_plan_primary</replaceable> </optional>
+  | <replaceable>json_table_plan_primary</replaceable> { UNION <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+  | <replaceable>json_table_plan_primary</replaceable> { CROSS <replaceable>json_table_plan_primary</replaceable> } <optional>...</optional>
+<phrase>
+<replaceable>json_table_plan_primary</replaceable> is:
+</phrase>
+    <replaceable>json_path_name</replaceable> | ( <replaceable>json_table_plan</replaceable> )
 
 </synopsis>
 
@@ -19381,7 +19392,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
       joined to the row that generated them, so you do not have to explicitly join
       the constructed view with the original table holding <acronym>JSON</acronym>
       data. Optionally, you can specify how to join the columns returned
-      by <literal>NESTED PATH</literal> using the <literal>PLAN DEFAULT</literal> clause.
+      by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
      </para>
 
      <para>
@@ -19566,7 +19577,7 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
     </para>
 
     <para>
-     You can use the <literal>PLAN DEFAULT</literal> clause to define how
+     You can use the <literal>PLAN</literal> clause to define how
      to join the columns returned by <replaceable>NESTED PATH</replaceable> clauses.
     </para>
     </listitem>
@@ -19593,18 +19604,31 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
    <varlistentry>
     <term>
-     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+     <literal>AS <replaceable>json_path_name</replaceable></literal>
     </term>
     <listitem>
-     <para>
-      Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
-      clauses to the constructed view. The <literal>INNER</literal> and
-      <literal>OUTER</literal> options define the joining plan for parent/child
-      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
-      affect the sibling columns. You can override the default plans for all
-      columns at once.
-     </para>
 
+    <para>
+     The optional <replaceable>json_path_name</replaceable> serves as an
+     identifier of the provided <replaceable>json_path_specification</replaceable>.
+     The path name must be unique and cannot coincide with column names.
+     When using the <literal>PLAN</literal> clause, you must specify the names
+     for all the paths, including the row pattern. Each path name can appear in
+     the <literal>PLAN</literal> clause only once.
+    </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN ( <replaceable class="parameter">json_table_plan</replaceable> )</literal>
+    </term>
+    <listitem>
+
+    <para>
+     Defines how to join the data returned by <replaceable>NESTED PATH</replaceable>
+     clauses to the constructed view.
+    </para>
     <para>
      To join columns with parent/child relationship, you can use:
     </para>
@@ -19683,6 +19707,23 @@ where <replaceable class="parameter">json_table_column</replaceable> is:
 
     </listitem>
    </varlistentry>
+
+   <varlistentry>
+    <term>
+     <literal>PLAN DEFAULT ( <replaceable>option</replaceable> <optional>, ... </optional> )</literal>
+    </term>
+    <listitem>
+     <para>
+      Overrides the default joining plans. The <literal>INNER</literal> and
+      <literal>OUTER</literal> options define the joining plan for parent/child
+      columns, while <literal>UNION</literal> and <literal>CROSS</literal>
+      affect the sibling columns. You can override the default plans for all columns at once.
+      Even though the path names are not included into the <literal>PLAN DEFAULT</literal>
+      clause, they must be provided for all the paths to conform to
+      the SQL/JSON standard.
+     </para>
+    </listitem>
+   </varlistentry>
   </variablelist>
     </sect5>
 
@@ -19714,9 +19755,35 @@ SELECT jt.* FROM
 </screen>
      </para>
 
-   </sect5>
-  </sect4>
-
+     <para>
+      Find a director that has done films in two different genres:
+<screen>
+SELECT
+  director1 AS director, title1, kind1, title2, kind2
+FROM
+  my_films,
+  JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
+    NESTED PATH '$[*]' AS films1 COLUMNS (
+      kind1 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film1 COLUMNS (
+        title1 text PATH '$.title',
+        director1 text PATH '$.director')
+    ),
+    NESTED PATH '$[*]' AS films2 COLUMNS (
+      kind2 text PATH '$.kind',
+      NESTED PATH '$.films[*]' AS film2 COLUMNS (
+        title2 text PATH '$.title',
+        director2 text PATH '$.director'
+      )
+    )
+   )
+   PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
+  ) AS jt
+ WHERE kind1 > kind2 AND director1 = director2;
+</screen>
+     </para>
+    </sect5>
+   </sect4>
   </sect3>
 
   <sect3 id="functions-sqljson-serializing">
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 617cb9aad8..e3071493bb 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2695,9 +2695,9 @@ _copyJsonTable(const JsonTable *from)
 
 	COPY_NODE_FIELD(common);
 	COPY_NODE_FIELD(columns);
+	COPY_NODE_FIELD(plan);
 	COPY_NODE_FIELD(on_error);
 	COPY_NODE_FIELD(alias);
-	COPY_SCALAR_FIELD(join_type);
 	COPY_SCALAR_FIELD(location);
 
 	return newnode;
@@ -2715,6 +2715,7 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(typeName);
 	COPY_STRING_FIELD(pathspec);
+	COPY_STRING_FIELD(pathname);
 	COPY_SCALAR_FIELD(format);
 	COPY_SCALAR_FIELD(wrapper);
 	COPY_SCALAR_FIELD(omit_quotes);
@@ -2726,6 +2727,24 @@ _copyJsonTableColumn(const JsonTableColumn *from)
 	return newnode;
 }
 
+/*
+ * _copyJsonTablePlan
+ */
+static JsonTablePlan *
+_copyJsonTablePlan(const JsonTablePlan *from)
+{
+	JsonTablePlan *newnode = makeNode(JsonTablePlan);
+
+	COPY_SCALAR_FIELD(plan_type);
+	COPY_SCALAR_FIELD(join_type);
+	COPY_STRING_FIELD(pathname);
+	COPY_NODE_FIELD(plan1);
+	COPY_NODE_FIELD(plan2);
+	COPY_SCALAR_FIELD(location);
+
+	return newnode;
+}
+
 /*
  * _copyJsonTableParent
  */
@@ -2735,9 +2754,9 @@ _copyJsonTableParent(const JsonTableParent *from)
 	JsonTableParent *newnode = makeNode(JsonTableParent);
 
 	COPY_NODE_FIELD(path);
+	COPY_STRING_FIELD(name);
 	COPY_NODE_FIELD(child);
 	COPY_SCALAR_FIELD(outerJoin);
-	COPY_SCALAR_FIELD(unionJoin);
 	COPY_SCALAR_FIELD(colMin);
 	COPY_SCALAR_FIELD(colMax);
 
@@ -5886,6 +5905,9 @@ copyObjectImpl(const void *from)
 		case T_JsonTableColumn:
 			retval = _copyJsonTableColumn(from);
 			break;
+		case T_JsonTablePlan:
+			retval = _copyJsonTablePlan(from);
+			break;
 		case T_JsonTableParent:
 			retval = _copyJsonTableParent(from);
 			break;
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 59cb8e58c7..56009e8480 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -181,9 +181,9 @@ static bool
 _equalJsonTableParent(const JsonTableParent *a, const JsonTableParent *b)
 {
 	COMPARE_NODE_FIELD(path);
+	COMPARE_STRING_FIELD(name);
 	COMPARE_NODE_FIELD(child);
 	COMPARE_SCALAR_FIELD(outerJoin);
-	COMPARE_SCALAR_FIELD(unionJoin);
 	COMPARE_SCALAR_FIELD(colMin);
 	COMPARE_SCALAR_FIELD(colMax);
 
diff --git a/src/backend/nodes/makefuncs.c b/src/backend/nodes/makefuncs.c
index cd6c300e7b..41e26a0fe6 100644
--- a/src/backend/nodes/makefuncs.c
+++ b/src/backend/nodes/makefuncs.c
@@ -867,6 +867,25 @@ makeJsonBehavior(JsonBehaviorType type, Node *default_expr)
 	return behavior;
 }
 
+/*
+ * makeJsonTableJoinedPlan -
+ *	   creates a joined JsonTablePlan node
+ */
+Node *
+makeJsonTableJoinedPlan(JsonTablePlanJoinType type, Node *plan1, Node *plan2,
+						int location)
+{
+	JsonTablePlan *n = makeNode(JsonTablePlan);
+
+	n->plan_type = JSTP_JOINED;
+	n->join_type = type;
+	n->plan1 = castNode(JsonTablePlan, plan1);
+	n->plan2 = castNode(JsonTablePlan, plan2);
+	n->location = location;
+
+	return (Node *) n;
+}
+
 /*
  * makeJsonEncoding -
  *	  converts JSON encoding name to enum JsonEncoding
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index da920f3d36..70a9aeb372 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1874,9 +1874,9 @@ _outJsonTableParent(StringInfo str, const JsonTableParent *node)
 	WRITE_NODE_TYPE("JSONTABPNODE");
 
 	WRITE_NODE_FIELD(path);
+	WRITE_STRING_FIELD(name);
 	WRITE_NODE_FIELD(child);
 	WRITE_BOOL_FIELD(outerJoin);
-	WRITE_BOOL_FIELD(unionJoin);
 	WRITE_INT_FIELD(colMin);
 	WRITE_INT_FIELD(colMax);
 }
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 4a9392647c..de1f6e0043 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1503,9 +1503,9 @@ _readJsonTableParent(void)
 	READ_LOCALS(JsonTableParent);
 
 	READ_NODE_FIELD(path);
+	READ_STRING_FIELD(name);
 	READ_NODE_FIELD(child);
 	READ_BOOL_FIELD(outerJoin);
-	READ_BOOL_FIELD(unionJoin);
 	READ_INT_FIELD(colMin);
 	READ_INT_FIELD(colMax);
 
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 088edd68fa..24934e0aaf 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -677,6 +677,18 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 					json_table_formatted_column_definition
 					json_table_exists_column_definition
 					json_table_nested_columns
+					json_table_plan_clause_opt
+					json_table_specific_plan
+					json_table_plan
+					json_table_plan_simple
+					json_table_plan_parent_child
+					json_table_plan_outer
+					json_table_plan_inner
+					json_table_plan_sibling
+					json_table_plan_union
+					json_table_plan_cross
+					json_table_plan_primary
+					json_table_default_plan
 
 %type <list>		json_name_and_value_list
 					json_value_expr_list
@@ -692,8 +704,6 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 %type <ival>		json_encoding
 					json_encoding_clause_opt
-					json_table_plan_clause_opt
-					json_table_default_plan
 					json_table_default_plan_choices
 					json_table_default_plan_inner_outer
 					json_table_default_plan_union_cross
@@ -15762,7 +15772,7 @@ json_table:
 					JsonTable *n = makeNode(JsonTable);
 					n->common = (JsonCommon *) $3;
 					n->columns = $4;
-					n->join_type = $5;
+					n->plan = (JsonTablePlan *) $5;
 					n->on_error = $6;
 					n->location = @1;
 					$$ = (Node *) n;
@@ -15884,12 +15894,15 @@ json_table_formatted_column_definition:
 		;
 
 json_table_nested_columns:
-			NESTED path_opt Sconst json_table_columns_clause
+			NESTED path_opt Sconst
+							json_as_path_name_clause_opt
+							json_table_columns_clause
 				{
 					JsonTableColumn *n = makeNode(JsonTableColumn);
 					n->coltype = JTC_NESTED;
 					n->pathspec = $3;
-					n->columns = $4;
+					n->pathname = $4;
+					n->columns = $5;
 					n->location = @1;
 					$$ = (Node *) n;
 				}
@@ -15901,12 +15914,84 @@ path_opt:
 		;
 
 json_table_plan_clause_opt:
-			json_table_default_plan					{ $$ = $1; }
-			| /* EMPTY */							{ $$ = JSTPJ_OUTER | JSTPJ_UNION; }
+			json_table_specific_plan				{ $$ = $1; }
+			| json_table_default_plan				{ $$ = $1; }
+			| /* EMPTY */							{ $$ = NULL; }
+		;
+
+json_table_specific_plan:
+			PLAN '(' json_table_plan ')'			{ $$ = $3; }
+		;
+
+json_table_plan:
+			json_table_plan_simple
+			| json_table_plan_parent_child
+			| json_table_plan_sibling
+		;
+
+json_table_plan_simple:
+			json_table_path_name
+				{
+					JsonTablePlan *n = makeNode(JsonTablePlan);
+					n->plan_type = JSTP_SIMPLE;
+					n->pathname = $1;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+		;
+
+json_table_plan_parent_child:
+			json_table_plan_outer
+			| json_table_plan_inner
+		;
+
+json_table_plan_outer:
+			json_table_plan_simple OUTER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_OUTER, $1, $3, @1); }
+		;
+
+json_table_plan_inner:
+			json_table_plan_simple INNER_P json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_INNER, $1, $3, @1); }
+		;
+
+json_table_plan_sibling:
+			json_table_plan_union
+			| json_table_plan_cross
+		;
+
+json_table_plan_union:
+			json_table_plan_primary UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+			| json_table_plan_union UNION json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_UNION, $1, $3, @1); }
+		;
+
+json_table_plan_cross:
+			json_table_plan_primary CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+			| json_table_plan_cross CROSS json_table_plan_primary
+				{ $$ = makeJsonTableJoinedPlan(JSTPJ_CROSS, $1, $3, @1); }
+		;
+
+json_table_plan_primary:
+			json_table_plan_simple						{ $$ = $1; }
+			| '(' json_table_plan ')'
+				{
+					castNode(JsonTablePlan, $2)->location = @1;
+					$$ = $2;
+				}
 		;
 
 json_table_default_plan:
-			PLAN DEFAULT '(' json_table_default_plan_choices ')' { $$ = $4; }
+			PLAN DEFAULT '(' json_table_default_plan_choices ')'
+			{
+				JsonTablePlan *n = makeNode(JsonTablePlan);
+				n->plan_type = JSTP_DEFAULT;
+				n->join_type = $4;
+				n->location = @1;
+				$$ = (Node *) n;
+			}
 		;
 
 json_table_default_plan_choices:
diff --git a/src/backend/parser/parse_jsontable.c b/src/backend/parser/parse_jsontable.c
index 5f2d647d9b..1ded7b56da 100644
--- a/src/backend/parser/parse_jsontable.c
+++ b/src/backend/parser/parse_jsontable.c
@@ -37,13 +37,16 @@ typedef struct JsonTableContext
 	JsonTable  *table;				/* untransformed node */
 	TableFunc  *tablefunc;			/* transformed node	*/
 	List	   *pathNames;			/* list of all path and columns names */
+	int			pathNameId;			/* path name id counter */
 	Oid			contextItemTypid;	/* type oid of context item (json/jsonb) */
 } JsonTableContext;
 
 static JsonTableParent * transformJsonTableColumns(JsonTableContext *cxt,
-													   List *columns,
-													   char *pathSpec,
-													   int location);
+												   JsonTablePlan *plan,
+												   List *columns,
+												   char *pathSpec,
+												   char **pathName,
+												   int location);
 
 static Node *
 makeStringConst(char *str, int location)
@@ -154,19 +157,150 @@ registerAllJsonTableColumns(JsonTableContext *cxt, List *columns)
 		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
 
 		if (jtc->coltype == JTC_NESTED)
+		{
+			if (jtc->pathname)
+				registerJsonTableColumn(cxt, jtc->pathname);
+
 			registerAllJsonTableColumns(cxt, jtc->columns);
+		}
 		else
+		{
 			registerJsonTableColumn(cxt, jtc->name);
+		}
+	}
+}
+
+/* Generate a new unique JSON_TABLE path name. */
+static char *
+generateJsonTablePathName(JsonTableContext *cxt)
+{
+	char		namebuf[32];
+	char	   *name = namebuf;
+
+	do
+	{
+		snprintf(namebuf, sizeof(namebuf), "json_table_path_%d",
+				 ++cxt->pathNameId);
+	} while (isJsonTablePathNameDuplicate(cxt, name));
+
+	name = pstrdup(name);
+	cxt->pathNames = lappend(cxt->pathNames, name);
+
+	return name;
+}
+
+/* Collect sibling path names from plan to the specified list. */
+static void
+collectSiblingPathsInJsonTablePlan(JsonTablePlan *plan, List **paths)
+{
+	if (plan->plan_type == JSTP_SIMPLE)
+		*paths = lappend(*paths, plan->pathname);
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			*paths = lappend(*paths, plan->plan1->pathname);
+		}
+		else if (plan->join_type == JSTPJ_CROSS ||
+				 plan->join_type == JSTPJ_UNION)
+		{
+			collectSiblingPathsInJsonTablePlan(plan->plan1, paths);
+			collectSiblingPathsInJsonTablePlan(plan->plan2, paths);
+		}
+		else
+			elog(ERROR, "invalid JSON_TABLE join type %d",
+				 plan->join_type);
+	}
+}
+
+/*
+ * Validate child JSON_TABLE plan by checking that:
+ *  - all nested columns have path names specified
+ *  - all nested columns have corresponding node in the sibling plan
+ *  - plan does not contain duplicate or extra nodes
+ */
+static void
+validateJsonTableChildPlan(ParseState *pstate, JsonTablePlan *plan,
+						   List *columns)
+{
+	ListCell   *lc1;
+	List	   *siblings = NIL;
+	int			nchildren = 0;
+
+	if (plan)
+		collectSiblingPathsInJsonTablePlan(plan, &siblings);
+
+	foreach(lc1, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc1));
+
+		if (jtc->coltype == JTC_NESTED)
+		{
+			ListCell   *lc2;
+			bool		found = false;
+
+			if (!jtc->pathname)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("nested JSON_TABLE columns must contain an explicit AS pathname specification if an explicit PLAN clause is used"),
+						 parser_errposition(pstate, jtc->location)));
+
+			/* find nested path name in the list of sibling path names */
+			foreach(lc2, siblings)
+			{
+				if ((found = !strcmp(jtc->pathname, lfirst(lc2))))
+					break;
+			}
+
+			if (!found)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("plan node for nested path %s was not found in plan", jtc->pathname),
+						 parser_errposition(pstate, jtc->location)));
+
+			nchildren++;
+		}
 	}
+
+	if (list_length(siblings) > nchildren)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("plan node contains some extra or duplicate sibling nodes"),
+				 parser_errposition(pstate, plan ? plan->location : -1)));
+}
+
+static JsonTableColumn *
+findNestedJsonTableColumn(List *columns, const char *pathname)
+{
+	ListCell   *lc;
+
+	foreach(lc, columns)
+	{
+		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+
+		if (jtc->coltype == JTC_NESTED &&
+			jtc->pathname &&
+			!strcmp(jtc->pathname, pathname))
+			return jtc;
+	}
+
+	return NULL;
 }
 
 static Node *
-transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc)
+transformNestedJsonTableColumn(JsonTableContext *cxt, JsonTableColumn *jtc,
+							   JsonTablePlan *plan)
 {
 	JsonTableParent *node;
+	char	   *pathname = jtc->pathname;
 
-	node = transformJsonTableColumns(cxt, jtc->columns, jtc->pathspec,
-									 jtc->location);
+	node = transformJsonTableColumns(cxt, plan, jtc->columns, jtc->pathspec,
+									 &pathname, jtc->location);
+	node->name = pstrdup(pathname);
 
 	return (Node *) node;
 }
@@ -184,34 +318,78 @@ makeJsonTableSiblingJoin(bool cross, Node *lnode, Node *rnode)
 }
 
 /*
- * Recursively transform child (nested) JSON_TABLE columns.
+ * Recursively transform child JSON_TABLE plan.
  *
- * Child columns are transformed into a binary tree of union/cross-joined
- * JsonTableSiblings.
+ * Default plan is transformed into a cross/union join of its nested columns.
+ * Simple and outer/inner plans are transformed into a JsonTableParent by
+ * finding and transforming corresponding nested column.
+ * Sibling plans are recursively transformed into a JsonTableSibling.
  */
 static Node *
-transformJsonTableChildColumns(JsonTableContext *cxt, List *columns)
+transformJsonTableChildPlan(JsonTableContext *cxt, JsonTablePlan *plan,
+							List *columns)
 {
-	Node	   *res = NULL;
-	ListCell   *lc;
-	bool		cross = cxt->table->join_type & JSTPJ_CROSS;
+	JsonTableColumn *jtc = NULL;
 
-	/* transform all nested columns into union/cros join */
-	foreach(lc, columns)
+	if (!plan || plan->plan_type == JSTP_DEFAULT)
 	{
-		JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
-		Node	   *node;
+		/* unspecified or default plan */
+		Node	   *res = NULL;
+		ListCell   *lc;
+		bool		cross = plan && (plan->join_type & JSTPJ_CROSS);
 
-		if (jtc->coltype != JTC_NESTED)
-			continue;
+		/* transform all nested columns into cross/union join */
+		foreach(lc, columns)
+		{
+			JsonTableColumn *jtc = castNode(JsonTableColumn, lfirst(lc));
+			Node *node;
 
-		node = transformNestedJsonTableColumn(cxt, jtc);
+			if (jtc->coltype != JTC_NESTED)
+				continue;
+
+			node = transformNestedJsonTableColumn(cxt, jtc, plan);
+
+			/* join transformed node with previous sibling nodes */
+			res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		}
 
-		/* join transformed node with previous sibling nodes */
-		res = res ? makeJsonTableSiblingJoin(cross, res, node) : node;
+		return res;
+	}
+	else if (plan->plan_type == JSTP_SIMPLE)
+	{
+		jtc = findNestedJsonTableColumn(columns, plan->pathname);
 	}
+	else if (plan->plan_type == JSTP_JOINED)
+	{
+		if (plan->join_type == JSTPJ_INNER ||
+			plan->join_type == JSTPJ_OUTER)
+		{
+			Assert(plan->plan1->plan_type == JSTP_SIMPLE);
+			jtc = findNestedJsonTableColumn(columns, plan->plan1->pathname);
+		}
+		else
+		{
+			Node	   *node1 =
+				transformJsonTableChildPlan(cxt, plan->plan1, columns);
+			Node	   *node2 =
+				transformJsonTableChildPlan(cxt, plan->plan2, columns);
+
+			return makeJsonTableSiblingJoin(plan->join_type == JSTPJ_CROSS,
+											node1, node2);
+		}
+	}
+	else
+		elog(ERROR, "invalid JSON_TABLE plan type %d", plan->plan_type);
 
-	return res;
+	if (!jtc)
+		ereport(ERROR,
+				(errcode(ERRCODE_SYNTAX_ERROR),
+				 errmsg("invalid JSON_TABLE plan"),
+				 errdetail("path name was %s not found in nested columns list",
+						   plan->pathname),
+				 parser_errposition(cxt->pstate, plan->location)));
+
+	return transformNestedJsonTableColumn(cxt, jtc, plan);
 }
 
 /* Check whether type is json/jsonb, array, or record. */
@@ -376,19 +554,80 @@ makeParentJsonTableNode(JsonTableContext *cxt, char *pathSpec, List *columns)
 }
 
 static JsonTableParent *
-transformJsonTableColumns(JsonTableContext *cxt, List *columns, char *pathSpec,
+transformJsonTableColumns(JsonTableContext *cxt, JsonTablePlan *plan,
+						  List *columns, char *pathSpec, char **pathName,
 						  int location)
 {
 	JsonTableParent *node;
+	JsonTablePlan *childPlan;
+	bool		defaultPlan = !plan || plan->plan_type == JSTP_DEFAULT;
+
+	if (!*pathName)
+	{
+		if (cxt->table->plan)
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE expression"),
+					 errdetail("JSON_TABLE columns must contain "
+							   "explicit AS pathname specification if "
+							   "explicit PLAN clause is used"),
+					parser_errposition(cxt->pstate, location)));
+
+		*pathName = generateJsonTablePathName(cxt);
+	}
+
+	if (defaultPlan)
+		childPlan = plan;
+	else
+	{
+		/* validate parent and child plans */
+		JsonTablePlan *parentPlan;
+
+		if (plan->plan_type == JSTP_JOINED)
+		{
+			if (plan->join_type != JSTPJ_INNER &&
+				plan->join_type != JSTPJ_OUTER)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("invalid JSON_TABLE plan"),
+						 errdetail("expected INNER or OUTER JSON_TABLE plan node"),
+						 parser_errposition(cxt->pstate, plan->location)));
+
+			parentPlan = plan->plan1;
+			childPlan = plan->plan2;
+
+			Assert(parentPlan->plan_type != JSTP_JOINED);
+			Assert(parentPlan->pathname);
+		}
+		else
+		{
+			parentPlan = plan;
+			childPlan = NULL;
+		}
+
+		if (strcmp(parentPlan->pathname, *pathName))
+			ereport(ERROR,
+					(errcode(ERRCODE_SYNTAX_ERROR),
+					 errmsg("invalid JSON_TABLE plan"),
+					 errdetail("path name mismatch: expected %s but %s is given",
+							   *pathName, parentPlan->pathname),
+					 parser_errposition(cxt->pstate, plan->location)));
+
+		validateJsonTableChildPlan(cxt->pstate, childPlan, columns);
+	}
 
 	/* transform only non-nested columns */
 	node = makeParentJsonTableNode(cxt, pathSpec, columns);
+	node->name = pstrdup(*pathName);
 
-	/* transform recursively nested columns */
-	node->child = transformJsonTableChildColumns(cxt, columns);
-
-	node->outerJoin = cxt->table->join_type & JSTPJ_OUTER;
-	node->unionJoin = cxt->table->join_type & JSTPJ_UNION;
+	if (childPlan || defaultPlan)
+	{
+		/* transform recursively nested columns */
+		node->child = transformJsonTableChildPlan(cxt, childPlan, columns);
+		if (node->child)
+			node->outerJoin = !plan || (plan->join_type & JSTPJ_OUTER);
+		/* else: default plan case, no children found */
+	}
 
 	return node;
 }
@@ -406,7 +645,9 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	JsonTableContext cxt;
 	TableFunc  *tf = makeNode(TableFunc);
 	JsonFuncExpr *jfe = makeNode(JsonFuncExpr);
+	JsonTablePlan *plan = jt->plan;
 	JsonCommon *jscommon;
+	char	   *rootPathName = jt->common->pathname;
 	char	   *rootPath;
 	bool		is_lateral;
 
@@ -414,9 +655,31 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 	cxt.table = jt;
 	cxt.tablefunc = tf;
 	cxt.pathNames = NIL;
+	cxt.pathNameId = 0;
+
+	if (rootPathName)
+		registerJsonTableColumn(&cxt, rootPathName);
 
 	registerAllJsonTableColumns(&cxt, jt->columns);
 
+#if 0 /* XXX it' unclear from the standard whether root path name is mandatory or not */
+	if (plan && plan->plan_type != JSTP_DEFAULT && !rootPathName)
+	{
+		/* Assign root path name and create corresponding plan node */
+		JsonTablePlan *rootNode = makeNode(JsonTablePlan);
+		JsonTablePlan *rootPlan = (JsonTablePlan *)
+				makeJsonTableJoinedPlan(JSTPJ_OUTER, (Node *) rootNode,
+										(Node *) plan, jt->location);
+
+		rootPathName = generateJsonTablePathName(&cxt);
+
+		rootNode->plan_type = JSTP_SIMPLE;
+		rootNode->pathname = rootPathName;
+
+		plan = rootPlan;
+	}
+#endif
+
 	jscommon = copyObject(jt->common);
 	jscommon->pathspec = makeStringConst(pstrdup("$"), -1);
 
@@ -452,7 +715,8 @@ transformJsonTable(ParseState *pstate, JsonTable *jt)
 
 	rootPath = castNode(A_Const, jt->common->pathspec)->val.sval.sval;
 
-	tf->plan = (Node *) transformJsonTableColumns(&cxt, jt->columns, rootPath,
+	tf->plan = (Node *) transformJsonTableColumns(&cxt, plan, jt->columns,
+												  rootPath, &rootPathName,
 												  jt->common->location);
 
 	tf->ordinalitycol = -1;		/* undefine ordinality column number */
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 46a492dc95..5ad9d01398 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11131,10 +11131,54 @@ get_json_table_nested_columns(TableFunc *tf, Node *node,
 		 appendStringInfoChar(context->buf, ' ');
 		 appendContextKeyword(context,  "NESTED PATH ", 0, 0, 0);
 		 get_const_expr(n->path, context, -1);
+		 appendStringInfo(context->buf, " AS %s", quote_identifier(n->name));
 		 get_json_table_columns(tf, n, context, showimplicit);
 	}
 }
 
+/*
+ * get_json_table_plan - Parse back a JSON_TABLE plan
+ */
+static void
+get_json_table_plan(TableFunc *tf, Node *node, deparse_context *context,
+					bool parenthesize)
+{
+	if (parenthesize)
+		appendStringInfoChar(context->buf, '(');
+
+	if (IsA(node, JsonTableSibling))
+	{
+		JsonTableSibling *n = (JsonTableSibling *) node;
+
+		get_json_table_plan(tf, n->larg, context,
+							IsA(n->larg, JsonTableSibling) ||
+							castNode(JsonTableParent, n->larg)->child);
+
+		appendStringInfoString(context->buf, n->cross ? " CROSS " : " UNION ");
+
+		get_json_table_plan(tf, n->rarg, context,
+							IsA(n->rarg, JsonTableSibling) ||
+							castNode(JsonTableParent, n->rarg)->child);
+	}
+	else
+	{
+		 JsonTableParent *n = castNode(JsonTableParent, node);
+
+		 appendStringInfoString(context->buf, quote_identifier(n->name));
+
+		 if (n->child)
+		 {
+			appendStringInfoString(context->buf,
+								   n->outerJoin ? " OUTER " : " INNER ");
+			get_json_table_plan(tf, n->child, context,
+								IsA(n->child, JsonTableSibling));
+		 }
+	}
+
+	if (parenthesize)
+		appendStringInfoChar(context->buf, ')');
+}
+
 /*
  * get_json_table_columns - Parse back JSON_TABLE columns
  */
@@ -11263,6 +11307,8 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_const_expr(root->path, context, -1);
 
+	appendStringInfo(buf, " AS %s", quote_identifier(root->name));
+
 	if (jexpr->passing_values)
 	{
 		ListCell   *lc1, *lc2;
@@ -11295,14 +11341,9 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
 
 	get_json_table_columns(tf, root, context, showimplicit);
 
-	if (!root->outerJoin || !root->unionJoin)
-	{
-		appendStringInfoChar(buf, ' ');
-		appendContextKeyword(context, "PLAN DEFAULT", 0, 0, 0);
-		appendStringInfo(buf, "(%s, %s)",
-						 root->outerJoin ? "OUTER" : "INNER",
-						 root->unionJoin ? "UNION" : "CROSS");
-	}
+	appendStringInfoChar(buf, ' ');
+	appendContextKeyword(context, "PLAN ", 0, 0, 0);
+	get_json_table_plan(tf, (Node *) root, context, true);
 
 	if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
 		get_json_behavior(jexpr->on_error, context, "ERROR");
diff --git a/src/include/nodes/makefuncs.h b/src/include/nodes/makefuncs.h
index 872f2f0828..c717468eb3 100644
--- a/src/include/nodes/makefuncs.h
+++ b/src/include/nodes/makefuncs.h
@@ -110,6 +110,8 @@ extern JsonFormat *makeJsonFormat(JsonFormatType type, JsonEncoding encoding,
 								  int location);
 extern JsonValueExpr *makeJsonValueExpr(Expr *expr, JsonFormat *format);
 extern JsonBehavior *makeJsonBehavior(JsonBehaviorType type, Node *expr);
+extern Node *makeJsonTableJoinedPlan(JsonTablePlanJoinType type,
+									 Node *plan1, Node *plan2, int location);
 extern Node *makeJsonKeyValue(Node *key, Node *value);
 extern Node *makeJsonIsPredicate(Node *expr, JsonFormat *format,
 								 JsonValueType vtype, bool unique_keys,
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 58b61cf3ab..b883b6e39f 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -513,6 +513,7 @@ typedef enum NodeTag
 	T_JsonIsPredicate,
 	T_JsonTable,
 	T_JsonTableColumn,
+	T_JsonTablePlan,
 	T_JsonCommon,
 	T_JsonArgument,
 	T_JsonKeyValue,
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 57ea498e3c..bc64e85246 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1649,6 +1649,7 @@ typedef struct JsonTableColumn
 	char	   *name;				/* column name */
 	TypeName   *typeName;			/* column type name */
 	JsonPathSpec pathspec;			/* path specification, if any */
+	char	   *pathname;			/* path name, if any */
 	JsonFormat *format;				/* JSON format clause, if specified */
 	JsonWrapper	wrapper;			/* WRAPPER behavior for formatted columns */
 	bool		omit_quotes;		/* omit or keep quotes on scalar strings? */
@@ -1658,6 +1659,17 @@ typedef struct JsonTableColumn
 	int			location;			/* token location, or -1 if unknown */
 } JsonTableColumn;
 
+/*
+ * JsonTablePlanType -
+ *		flags for JSON_TABLE plan node types representation
+ */
+typedef enum JsonTablePlanType
+{
+	JSTP_DEFAULT,
+	JSTP_SIMPLE,
+	JSTP_JOINED,
+} JsonTablePlanType;
+
 /*
  * JsonTablePlanJoinType -
  *		flags for JSON_TABLE join types representation
@@ -1670,6 +1682,23 @@ typedef enum JsonTablePlanJoinType
 	JSTPJ_UNION = 0x08,
 } JsonTablePlanJoinType;
 
+typedef struct JsonTablePlan JsonTablePlan;
+
+/*
+ * JsonTablePlan -
+ *		untransformed representation of JSON_TABLE plan node
+ */
+struct JsonTablePlan
+{
+	NodeTag		type;
+	JsonTablePlanType plan_type;		/* plan type */
+	JsonTablePlanJoinType join_type;	/* join type (for joined plan only) */
+	JsonTablePlan *plan1;				/* first joined plan */
+	JsonTablePlan *plan2;				/* second joined plan */
+	char	   *pathname;				/* path name (for simple plan only) */
+	int			location;				/* token location, or -1 if unknown */
+};
+
 /*
  * JsonTable -
  *		untransformed representation of JSON_TABLE
@@ -1679,7 +1708,7 @@ typedef struct JsonTable
 	NodeTag		type;
 	JsonCommon *common;					/* common JSON path syntax fields */
 	List	   *columns;				/* list of JsonTableColumn */
-	JsonTablePlanJoinType join_type;	/* DEFAULT PLAN join type */
+	JsonTablePlan *plan;				/* join plan, if specified */
 	JsonBehavior *on_error;				/* ON ERROR behavior, if specified */
 	Alias	   *alias;					/* table alias in FROM clause */
 	bool		lateral;				/* does it have LATERAL prefix? */
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 098f4c96ab..01d0f76df3 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1473,9 +1473,9 @@ typedef struct JsonTableParent
 {
 	NodeTag		type;
 	Const	   *path;		/* jsonpath constant */
+	char	   *name;		/* path name */
 	Node	   *child;		/* nested columns, if any */
 	bool		outerJoin;	/* outer or inner join for nested columns? */
-	bool		unionJoin;	/* union or cross join for nested columns? */
 	int			colMin;		/* min column index in the resulting column list */
 	int			colMax;		/* max column index in the resulting column list */
 	bool		errorOnError; /* ERROR/EMPTY ON ERROR behavior */
diff --git a/src/test/regress/expected/jsonb_sqljson.out b/src/test/regress/expected/jsonb_sqljson.out
index 0d8c5d6add..2db7023206 100644
--- a/src/test/regress/expected/jsonb_sqljson.out
+++ b/src/test/regress/expected/jsonb_sqljson.out
@@ -1136,18 +1136,18 @@ SELECT * FROM
 			ia int[] PATH '$',
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -1187,7 +1187,7 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
     "json_table".a21,
     "json_table".a22
    FROM JSON_TABLE(
-            'null'::jsonb, '$[*]'
+            'null'::jsonb, '$[*]' AS json_table_path_1
             PASSING
                 1 + 2 AS a,
                 '"foo"'::json AS "b c"
@@ -1218,34 +1218,35 @@ CREATE OR REPLACE VIEW public.jsonb_table_view AS
                 ia integer[] PATH '$',
                 ta text[] PATH '$',
                 jba jsonb[] PATH '$',
-                NESTED PATH '$[1]'
+                NESTED PATH '$[1]' AS p1
                 COLUMNS (
                     a1 integer PATH '$."a1"',
                     b1 text PATH '$."b1"',
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p1 1"
                     COLUMNS (
                         a11 text PATH '$."a11"'
                     )
                 ),
-                NESTED PATH '$[2]'
+                NESTED PATH '$[2]' AS p2
                 COLUMNS (
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS "p2:1"
                     COLUMNS (
                         a21 text PATH '$."a21"'
                     ),
-                    NESTED PATH '$[*]'
+                    NESTED PATH '$[*]' AS p22
                     COLUMNS (
                         a22 text PATH '$."a22"'
                     )
                 )
             )
+            PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22))))
         )
 EXPLAIN (COSTS OFF, VERBOSE) SELECT * FROM jsonb_table_view;
-                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                         QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                                          
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  Table Function Scan on "json_table"
    Output: "json_table".id, "json_table".id2, "json_table"."int", "json_table".text, "json_table"."char(4)", "json_table".bool, "json_table"."numeric", "json_table".domain, "json_table".js, "json_table".jb, "json_table".jst, "json_table".jsc, "json_table".jsv, "json_table".jsb, "json_table".jsbq, "json_table".aaa, "json_table".aaa1, "json_table".exists1, "json_table".exists2, "json_table".exists3, "json_table".js2, "json_table".jsb2w, "json_table".jsb2q, "json_table".ia, "json_table".ta, "json_table".jba, "json_table".a1, "json_table".b1, "json_table".a11, "json_table".a21, "json_table".a22
-   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' COLUMNS ( NESTED PATH '$[*]' COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' COLUMNS (a22 text PATH '$."a22"'))))
+   Table Function Call: JSON_TABLE('null'::jsonb, '$[*]' AS json_table_path_1 PASSING 3 AS a, '"foo"'::jsonb AS "b c" COLUMNS (id FOR ORDINALITY, id2 FOR ORDINALITY, "int" integer PATH '$', text text PATH '$', "char(4)" character(4) PATH '$', bool boolean PATH '$', "numeric" numeric PATH '$', domain jsonb_test_domain PATH '$', js json PATH '$', jb jsonb PATH '$', jst text FORMAT JSON PATH '$', jsc character(4) FORMAT JSON PATH '$', jsv character varying(4) FORMAT JSON PATH '$', jsb jsonb PATH '$', jsbq jsonb PATH '$' OMIT QUOTES, aaa integer PATH '$."aaa"', aaa1 integer PATH '$."aaa"', exists1 boolean EXISTS PATH '$."aaa"', exists2 integer EXISTS PATH '$."aaa"' TRUE ON ERROR, exists3 text EXISTS PATH 'strict $."aaa"' UNKNOWN ON ERROR, js2 json PATH '$', jsb2w jsonb PATH '$' WITH UNCONDITIONAL WRAPPER, jsb2q jsonb PATH '$' OMIT QUOTES, ia integer[] PATH '$', ta text[] PATH '$', jba jsonb[] PATH '$', NESTED PATH '$[1]' AS p1 COLUMNS (a1 integer PATH '$."a1"', b1 text PATH '$."b1"', NESTED PATH '$[*]' AS "p1 1" COLUMNS (a11 text PATH '$."a11"')), NESTED PATH '$[2]' AS p2 COLUMNS ( NESTED PATH '$[*]' AS "p2:1" COLUMNS (a21 text PATH '$."a21"'), NESTED PATH '$[*]' AS p22 COLUMNS (a22 text PATH '$."a22"'))) PLAN (json_table_path_1 OUTER ((p1 OUTER "p1 1") UNION (p2 OUTER ("p2:1" UNION p22)))))
 (3 rows)
 
 DROP VIEW jsonb_table_view;
@@ -1337,13 +1338,49 @@ ERROR:  cannot cast type boolean to jsonb
 LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
                                                              ^
 -- JSON_TABLE: nested paths and plans
+-- Should fail (JSON_TABLE columns must contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb '[]', '$' -- AS <path name> required here
+         ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 4:   NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+          ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
 -- Should fail (column names must be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		a int
+	)
+) jt;
+ERROR:  duplicate JSON_TABLE column name: a
+HINT:  JSON_TABLE column names must be distinct from one another
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 ERROR:  duplicate JSON_TABLE column name: a
@@ -1352,10 +1389,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -1364,22 +1400,209 @@ HINT:  JSON_TABLE column names must be distinct from one another
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
-ERROR:  duplicate JSON_TABLE column name: b
+ERROR:  duplicate JSON_TABLE column name: a
 HINT:  JSON_TABLE column names must be distinct from one another
+-- JSON_TABLE: plan validation
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p1)
+                ^
+DETAIL:  path name mismatch: expected p0 but p1 is given
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 4:   NESTED PATH '$' AS p1 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p1 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 UNION p1 UNION p11)
+                ^
+DETAIL:  expected INNER or OUTER JSON_TABLE plan node
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 8:   NESTED PATH '$' AS p2 COLUMNS (
+          ^
+DETAIL:  plan node for nested path p2 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 5:    NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+           ^
+DETAIL:  plan node for nested path p11 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 12:  PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+                         ^
+DETAIL:  plan node contains some extra or duplicate sibling nodes
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 6:    NESTED PATH '$' AS p12 COLUMNS ( bar int )
+           ^
+DETAIL:  plan node for nested path p12 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+ERROR:  invalid JSON_TABLE plan
+LINE 9:    NESTED PATH '$' AS p21 COLUMNS ( baz int )
+           ^
+DETAIL:  plan node for nested path p21 was not found in plan
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+ bar | foo | baz 
+-----+-----+-----
+(0 rows)
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+ERROR:  invalid JSON_TABLE expression
+LINE 2:  jsonb 'null', 'strict $[*]' -- without root path name
+         ^
+DETAIL:  JSON_TABLE columns must contain explicit AS pathname specification if explicit PLAN clause is used
 -- JSON_TABLE: plan execution
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
 INSERT INTO jsonb_table_test
@@ -1397,12 +1620,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
  n | a  | b | c  
@@ -1426,12 +1649,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
@@ -1450,18 +1673,78 @@ from
  4 | -1 | 2 |   
 (11 rows)
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(11 rows)
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+ n | a  | c  | b 
+---+----+----+---
+ 1 |  1 |    |  
+ 2 |  2 | 10 |  
+ 2 |  2 |    |  
+ 2 |  2 | 20 |  
+ 2 |  2 |    | 1
+ 2 |  2 |    | 2
+ 2 |  2 |    | 3
+ 3 |  3 |    | 1
+ 3 |  3 |    | 2
+ 4 | -1 |    | 1
+ 4 | -1 |    | 2
+(11 rows)
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
@@ -1479,18 +1762,47 @@ from
  4 | -1 | 2 |   
 (10 rows)
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 2 |  2 | 1 |   
+ 2 |  2 | 2 |   
+ 2 |  2 | 3 |   
+ 2 |  2 |   | 10
+ 2 |  2 |   |   
+ 2 |  2 |   | 20
+ 3 |  3 | 1 |   
+ 3 |  3 | 2 |   
+ 4 | -1 | 1 |   
+ 4 | -1 | 2 |   
+(10 rows)
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
@@ -1507,18 +1819,46 @@ from
  2 | 2 | 3 | 20
 (9 rows)
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+ n | a | b | c  
+---+---+---+----
+ 2 | 2 | 1 | 10
+ 2 | 2 | 1 |   
+ 2 | 2 | 1 | 20
+ 2 | 2 | 2 | 10
+ 2 | 2 | 2 |   
+ 2 | 2 | 2 | 20
+ 2 | 2 | 3 | 10
+ 2 | 2 | 3 |   
+ 2 | 2 | 3 | 20
+(9 rows)
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
@@ -1538,6 +1878,90 @@ from
  4 | -1 |   |   
 (12 rows)
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+ n | a  | b | c  
+---+----+---+----
+ 1 |  1 |   |   
+ 2 |  2 | 1 | 10
+ 2 |  2 | 1 |   
+ 2 |  2 | 1 | 20
+ 2 |  2 | 2 | 10
+ 2 |  2 | 2 |   
+ 2 |  2 | 2 | 20
+ 2 |  2 | 3 | 10
+ 2 |  2 | 3 |   
+ 2 |  2 | 3 | 20
+ 3 |  3 |   |   
+ 4 | -1 |   |   
+(12 rows)
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
+ n | a |      b       | b1  |  c   | c1 |  b  
+---+---+--------------+-----+------+----+-----
+ 1 | 1 | [1, 10]      |   1 | 1    |    | 101
+ 1 | 1 | [1, 10]      |   1 | null |    | 101
+ 1 | 1 | [1, 10]      |   1 | 2    |    | 101
+ 1 | 1 | [1, 10]      |  10 | 1    |    | 110
+ 1 | 1 | [1, 10]      |  10 | null |    | 110
+ 1 | 1 | [1, 10]      |  10 | 2    |    | 110
+ 1 | 1 | [2]          |   2 | 1    |    | 102
+ 1 | 1 | [2]          |   2 | null |    | 102
+ 1 | 1 | [2]          |   2 | 2    |    | 102
+ 1 | 1 | [3, 30, 300] |   3 | 1    |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | null |    | 103
+ 1 | 1 | [3, 30, 300] |   3 | 2    |    | 103
+ 1 | 1 | [3, 30, 300] |  30 | 1    |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | null |    | 130
+ 1 | 1 | [3, 30, 300] |  30 | 2    |    | 130
+ 1 | 1 | [3, 30, 300] | 300 | 1    |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | null |    | 400
+ 1 | 1 | [3, 30, 300] | 300 | 2    |    | 400
+ 2 | 2 |              |     |      |    |    
+ 3 |   |              |     |      |    |    
+(20 rows)
+
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
 FROM
diff --git a/src/test/regress/sql/jsonb_sqljson.sql b/src/test/regress/sql/jsonb_sqljson.sql
index 9ad1047485..930d86c90e 100644
--- a/src/test/regress/sql/jsonb_sqljson.sql
+++ b/src/test/regress/sql/jsonb_sqljson.sql
@@ -414,18 +414,18 @@ SELECT * FROM
 			ta text[] PATH '$',
 			jba jsonb[] PATH '$',
 
-			NESTED PATH '$[1]' COLUMNS (
+			NESTED PATH '$[1]' AS p1 COLUMNS (
 				a1 int,
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS "p1 1" COLUMNS (
 					a11 text
 				),
 				b1 text
 			),
-			NESTED PATH '$[2]' COLUMNS (
-				NESTED PATH '$[*]' COLUMNS (
+			NESTED PATH '$[2]' AS p2 COLUMNS (
+				NESTED PATH '$[*]' AS "p2:1" COLUMNS (
 					a21 text
 				),
-				NESTED PATH '$[*]' COLUMNS (
+				NESTED PATH '$[*]' AS p22 COLUMNS (
 					a22 text
 				)
 			)
@@ -478,13 +478,42 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
 
 -- JSON_TABLE: nested paths and plans
 
+-- Should fail (JSON_TABLE columns must contain explicit AS path
+-- specifications if explicit PLAN clause is used)
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' -- AS <path name> required here
+	COLUMNS (
+		foo int PATH '$'
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS path1
+	COLUMNS (
+		NESTED PATH '$' COLUMNS ( -- AS <path name> required here
+			foo int PATH '$'
+		)
+	)
+	PLAN DEFAULT (UNION)
+) jt;
+
 -- Should fail (column names must be distinct)
 SELECT * FROM JSON_TABLE(
-	jsonb '[]', '$'
+	jsonb '[]', '$' AS a
+	COLUMNS (
+		a int
+	)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb '[]', '$' AS a
 	COLUMNS (
-		a int,
-		b text,
-		a jsonb
+		b int,
+		NESTED PATH '$' AS a
+		COLUMNS (
+			c int
+		)
 	)
 ) jt;
 
@@ -492,10 +521,9 @@ SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
 		b int,
-		NESTED PATH '$'
+		NESTED PATH '$' AS b
 		COLUMNS (
-			c int,
-			b text
+			c int
 		)
 	)
 ) jt;
@@ -503,21 +531,176 @@ SELECT * FROM JSON_TABLE(
 SELECT * FROM JSON_TABLE(
 	jsonb '[]', '$'
 	COLUMNS (
-		NESTED PATH '$'
+		NESTED PATH '$' AS a
 		COLUMNS (
 			b int
 		),
 		NESTED PATH '$'
 		COLUMNS (
-			NESTED PATH '$'
+			NESTED PATH '$' AS a
 			COLUMNS (
-				c int,
-				b text
+				c int
 			)
 		)
 	)
 ) jt;
 
+-- JSON_TABLE: plan validation
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p1)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER p3)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 UNION p1 UNION p11)
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p13))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER (p1 CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 UNION p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER p11) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', '$[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS p2))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' AS p0
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN (p0 OUTER ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21)))
+) jt;
+
+SELECT * FROM JSON_TABLE(
+	jsonb 'null', 'strict $[*]' -- without root path name
+	COLUMNS (
+		NESTED PATH '$' AS p1 COLUMNS (
+			NESTED PATH '$' AS p11 COLUMNS ( foo int ),
+			NESTED PATH '$' AS p12 COLUMNS ( bar int )
+		),
+		NESTED PATH '$' AS p2 COLUMNS (
+			NESTED PATH '$' AS p21 COLUMNS ( baz int )
+		)
+	)
+	PLAN ((p1 INNER (p12 CROSS p11)) CROSS (p2 INNER p21))
+) jt;
+
 -- JSON_TABLE: plan execution
 
 CREATE TEMP TABLE jsonb_table_test (js jsonb);
@@ -538,12 +721,12 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 	) jt;
 
@@ -553,64 +736,174 @@ select
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, union)
 	) jt;
 
+-- specific plan (p outer (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb union pc))
+	) jt;
+
+-- specific plan (p outer (pc union pb))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pc union pb))
+	) jt;
+
 -- default plan (inner, union)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (inner)
 	) jt;
 
+-- specific plan (p inner (pb union pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb union pc))
+	) jt;
+
 -- default plan (inner, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (cross, inner)
 	) jt;
 
+-- specific plan (p inner (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p inner (pb cross pc))
+	) jt;
+
 -- default plan (outer, cross)
 select
 	jt.*
 from
 	jsonb_table_test jtt,
 	json_table (
-		jtt.js,'strict $[*]'
+		jtt.js,'strict $[*]' as p
 		columns (
 			n for ordinality,
 			a int path 'lax $.a' default -1 on empty,
-			nested path 'strict $.b[*]' columns ( b int path '$' ),
-			nested path 'strict $.c[*]' columns ( c int path '$' )
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
 		)
 		plan default (outer, cross)
 	) jt;
 
+-- specific plan (p outer (pb cross pc))
+select
+	jt.*
+from
+	jsonb_table_test jtt,
+	json_table (
+		jtt.js,'strict $[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on empty,
+			nested path 'strict $.b[*]' as pb columns ( b int path '$' ),
+			nested path 'strict $.c[*]' as pc columns ( c int path '$' )
+		)
+		plan (p outer (pb cross pc))
+	) jt;
+
+
+select
+	jt.*, b1 + 100 as b
+from
+	json_table (jsonb
+		'[
+			{"a":  1,  "b": [[1, 10], [2], [3, 30, 300]], "c": [1, null, 2]},
+			{"a":  2,  "b": [10, 20], "c": [1, null, 2]},
+			{"x": "3", "b": [11, 22, 33, 44]}
+		 ]',
+		'$[*]' as p
+		columns (
+			n for ordinality,
+			a int path 'lax $.a' default -1 on error,
+			nested path 'strict $.b[*]' as pb columns (
+				b text format json path '$',
+				nested path 'strict $[*]' as pb1 columns (
+					b1 int path '$'
+				)
+			),
+			nested path 'strict $.c[*]' as pc columns (
+				c text format json path '$',
+				nested path 'strict $[*]' as pc1 columns (
+					c1 int path '$'
+				)
+			)
+		)
+		--plan default(outer, cross)
+		plan(p outer ((pb inner pb1) cross (pc outer pc1)))
+	) jt;
 
 -- Should succeed (JSON arguments are passed to root and nested paths)
 SELECT *
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index a8f8005941..aa1e143f14 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -1242,7 +1242,9 @@ JsonTableColumnType
 JsonTableContext
 JsonTableJoinState
 JsonTableParent
+JsonTablePlan
 JsonTablePlanJoinType
+JsonTablePlanType
 JsonTableScanState
 JsonTableSibling
 JsonTokenType
-- 
2.25.1

#85Zhihong Yu
zyu@yugabyte.com
In reply to: Andrew Dunstan (#84)
Re: SQL/JSON: JSON_TABLE

On Fri, Mar 25, 2022 at 1:30 PM Andrew Dunstan <andrew@dunslane.net> wrote:

On 3/22/22 10:55, Daniel Gustafsson wrote:

On 22 Mar 2022, at 16:31, Andrew Dunstan <andrew@dunslane.net> wrote:
I'm planning on pushing the functions patch set this week and json-table
next week.

My comments from 30827B3C-EDF6-4D41-BBF1-2981818744A8@yesql.se are yet

to be

addressed (or at all responded to) in this patchset. I'll paste the

ones which

still apply to make it easier:

I think I have fixed all those. See attached. I haven't prepared a new
patch set for SQL/JSON functions because there's just one typo to fix,
but I won't forget it. Please let me know if there's anything else you see.

At this stage I think I have finished with the actual code, and I'm
concentrating on improving the docs a bit.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

Hi,
w.r.t. 0001-SQL-JSON-functions-without-sql_json-GUC-v59.patch :

+                   Datum      *innermost_caseval =
state->innermost_caseval;
+                   bool       *innermost_isnull =
state->innermost_casenull;
+
+                   state->innermost_caseval = resv;
+                   state->innermost_casenull = resnull;
+
+                   ExecInitExprRec(jve->formatted_expr, state, resv,
resnull);
+
+                   state->innermost_caseval = innermost_caseval;
+                   state->innermost_casenull = innermost_isnull;

Code similar to the above block appears at least twice. Maybe extract into
a helper func to reuse code.

+ * Evaluate a JSON path variable caching computed value.
+ */
+int
+EvalJsonPathVar(void *cxt, char *varName, int varNameLen,

Please add description for return value in the comment.

+                   if (formatted && IsA(formatted, Const))
+                       return formatted;

If formatted is NULL, it cannot be Const. So the if can be simplified:

+ if (IsA(formatted, Const))

For transformJsonConstructorOutput(), it seems the variable have_json is
not used - you can drop the variable.

+ * Coerce a expression in JSON DEFAULT behavior to the target output type.

a expression -> an expression

Cheers

#86Erik Rijkers
er@xs4all.nl
In reply to: Andrew Dunstan (#84)
1 attachment(s)
Re: SQL/JSON: JSON_TABLE

Op 25-03-2022 om 21:30 schreef Andrew Dunstan:

On 3/22/22 10:55, Daniel Gustafsson wrote:

On 22 Mar 2022, at 16:31, Andrew Dunstan <andrew@dunslane.net> wrote:
I'm planning on pushing the functions patch set this week and json-table
next week.

My comments from 30827B3C-EDF6-4D41-BBF1-2981818744A8@yesql.se are yet to be
addressed (or at all responded to) in this patchset. I'll paste the ones which
still apply to make it easier:

I think I have fixed all those. See attached. I haven't prepared a new
patch set for SQL/JSON functions because there's just one typo to fix,
but I won't forget it. Please let me know if there's anything else you see.

At this stage I think I have finished with the actual code, and I'm
concentrating on improving the docs a bit.

[ v59 ]

FWIW, I went through func.sgml (of v59) once.

Erik Rijkers

Attachments:

func.sgml.20220326.difftext/x-patch; charset=UTF-8; name=func.sgml.20220326.diffDownload
--- doc/src/sgml/func.sgml.orig	2022-03-25 22:17:13.908660140 +0100
+++ doc/src/sgml/func.sgml	2022-03-26 12:08:46.593271826 +0100
@@ -17673,8 +17673,8 @@
      <title>Description</title>
 
      <para>
-      <function>JSON</function> function generates a <acronym>JSON</acronym>
-      from a text data.
+      The <function>JSON</function> function generates <acronym>JSON</acronym>
+      from text data.
      </para>
     </sect5>
 
@@ -17688,7 +17688,7 @@
         <listitem>
          <para>
           String expression that provides the <acronym>JSON</acronym> text data.
-          Accepted any character strings (<type>text</type>, <type>char</type>, etc.)
+          Accepts any character strings (<type>text</type>, <type>char</type>, etc.)
           or binary strings (<type>bytea</type>) in UTF8 encoding.
           For null input, <acronym>SQL</acronym> null value is returned.
          </para>
@@ -17757,7 +17757,7 @@
     <sect5>
      <title>Examples</title>
      <para>
-      Construct a JSON the provided strings:
+      Construct JSON using the provided strings:
      </para>
 <screen>
 SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
@@ -17794,8 +17794,8 @@
      <title>Description</title>
 
      <para>
-      <function>JSON_SCALAR</function> function generates a scalar
-      <acronym>JSON</acronym> from a <acronym>SQL</acronym> data.
+      The <function>JSON_SCALAR</function> function generates scalar
+      <acronym>JSON</acronym> from <acronym>SQL</acronym> data.
      </para>
     </sect5>
 
@@ -17808,11 +17808,11 @@
         </term>
         <listitem>
          <para>
-          Expression that provides the data for constructing a
+          Expression that provides the data for constructing
           <acronym>JSON</acronym>.
           For null input, <acronym>SQL</acronym>  null
-          (not a <acronym>JSON</acronym> null) value is returned.
-          For any scalar other than a number, a Boolean, the text representation
+          (not <acronym>JSON</acronym> null) value is returned.
+          For any scalar other than a number or a Boolean, the text representation
           will be used, with escaping as necessary to make it a valid
           <acronym>JSON</acronym> string value.
           For details, see
@@ -17847,7 +17847,7 @@
     <sect5>
      <title>Examples</title>
      <para>
-      Construct a JSON from the provided values various types:
+      Construct JSON from provided values of various type:
      </para>
 <screen>
 SELECT JSON_SCALAR(123.45);
@@ -18753,7 +18753,7 @@
 <screen>
 -- Strict mode with ERROR on ERROR clause
 SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
-ERROR: Invalid SQL/JSON subscript
+ERROR:  jsonpath array subscript is out of bounds
 (1 row)
 </screen>
 
@@ -18795,11 +18795,11 @@
      <title>Description</title>
 
   <para>
-   <function>JSON_VALUE</function> function extracts a value from the provided
+   The <function>JSON_VALUE</function> function extracts a value from the provided
    <acronym>JSON</acronym> data and converts it to an <acronym>SQL</acronym> scalar.
    If the specified JSON path expression returns more than one
    <acronym>SQL/JSON</acronym> item, an error occurs. To extract
-   an <acronym>SQL/JSON</acronym> array or object, use <xref linkend="functions-jsonquery"/>.
+   an <acronym>SQL/JSON</acronym> array or object, see <xref linkend="functions-jsonquery"/>.
   </para>
     </sect5>
 
@@ -18885,19 +18885,19 @@
      </para>
 
 <screen>
-SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
+SELECT JSON_VALUE('"123.45"'::jsonb, '$' RETURNING float);
  json_value
 ------------
      123.45
 (1 row)
 
-SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
+SELECT JSON_VALUE('123.45'::jsonb, '$' RETURNING int ERROR ON ERROR);
  json_value
 ------------
         123
 (1 row)
 
-SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
+SELECT JSON_VALUE('"03:04 2015-02-01"'::jsonb, '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
  json_value 
 ------------
  2015-02-01
@@ -18907,10 +18907,10 @@
 ERROR:  invalid input syntax for integer: "123.45"
 
 SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
-ERROR: SQL/JSON scalar required
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
 
 SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
-ERROR: more than one SQL/JSON item
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
 </screen>
 
      <para>
@@ -18920,13 +18920,13 @@
      </para>
 <screen>
 SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
-ERROR: SQL/JSON scalar required
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
 
 SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
-ERROR: SQL/JSON scalar required
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
 
 SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
-ERROR: more than one SQL/JSON item
+ERROR:  JSON path expression in JSON_VALUE should return singleton scalar item
 
 SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
 1
@@ -18954,11 +18954,11 @@
      <title>Description</title>
 
   <para>
-   <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
+   The <function>JSON_QUERY</function> function extracts an <acronym>SQL/JSON</acronym>
    array or object from <acronym>JSON</acronym> data. This function must return
    a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
    items, you must wrap the result using the <literal>WITH WRAPPER</literal> clause.
-   To extract a single <acronym>SQL/JSON</acronym> value, you can use <xref linkend="functions-jsonvalue"/>.
+   To extract a single <acronym>SQL/JSON</acronym> value, see JSON_VALUE (<xref linkend="functions-jsonvalue"/>).
   </para>
     </sect5>
 
@@ -19119,7 +19119,8 @@
 SELECT
     JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
 FROM my_films;
-ERROR: more than one SQL/JSON item 
+ERROR:  JSON path expression in JSON_QUERY should return singleton item without wrapper
+HINT:  use WITH WRAPPER clause to wrap SQL/JSON item sequence into array
 </screen>
 
      <para>
#87Andrew Dunstan
andrew@dunslane.net
In reply to: Erik Rijkers (#86)
Re: SQL/JSON: JSON_TABLE

On 3/26/22 07:29, Erik Rijkers wrote:

Op 25-03-2022 om 21:30 schreef Andrew Dunstan:

On 3/22/22 10:55, Daniel Gustafsson wrote:

On 22 Mar 2022, at 16:31, Andrew Dunstan <andrew@dunslane.net> wrote:
I'm planning on pushing the functions patch set this week and
json-table
next week.

My comments from 30827B3C-EDF6-4D41-BBF1-2981818744A8@yesql.se are
yet to be
addressed (or at all responded to) in this patchset.  I'll paste the
ones which
still apply to make it easier:

I think I have fixed all those. See attached. I haven't prepared a new
patch set for SQL/JSON functions because there's just one typo to fix,
but I won't forget it. Please let me know if there's anything else
you see.

At this stage I think I have finished with the actual code, and I'm
concentrating on improving the docs a bit.

[ v59 ]

FWIW, I went through func.sgml (of v59) once.

Thanks, That will help.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#88Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#83)
Re: SQL/JSON: JSON_TABLE

On 3/24/22 18:54, Andrew Dunstan wrote:

On 3/5/22 09:35, Andrew Dunstan wrote:

On 3/4/22 15:05, Andrew Dunstan wrote:

On 3/4/22 13:13, Erikjan Rijkers wrote:

Op 04-03-2022 om 17:33 schreef Andrew Dunstan:

This set of patches deals with items 1..7 above, but not yet the ERROR
ON ERROR issue. It also makes some message cleanups, but there is more
to come in that area.

It is based on the latest SQL/JSON Functions patch set, which does not
include the sql_json GUC patch.

[0001-SQL-JSON-functions-without-sql_json-GUC-v56.patch]
[0002-JSON_TABLE-v56.patch]
[0003-JSON_TABLE-PLAN-DEFAULT-clause-v56.patch]
[0004-JSON_TABLE-PLAN-clause-v56.patch]

Hi,

I quickly tried the tests I already had and there are two statements
that stopped working:

testdb=# SELECT JSON('{"a": 123, "b": [true, "foo"], "a2": "bar"}'
RETURNING jsonb);
ERROR:  syntax error at or near "RETURNING"
LINE 1: ...SON('{"a": 123, "b": [true, "foo"], "a2": "bar"}' RETURNING
...

testdb=# select JSON_SCALAR(123.45 returning jsonb);
ERROR:  syntax error at or near "returning"
LINE 1: select JSON_SCALAR(123.45 returning jsonb)

  (the '^' pointer in both cases underneath 'RETURNING'

Yes, you're right, that was implemented as part of the GUC patch. I'll
try to split that out and send new patchsets with the RETURNING clause
but without the GUC (see upthread for reasons)

Here's a patchset with RETURNING for JSON() and JSON_SCALAR() but
without the GUC

Here's a new set with the latest sql/json functions patch and fixes for
some further node handling  inadequacies.

I have been wrestling with the docs in these patches, which are somewhat
haphazardly spread across the various patches, and tying myself up in
knots. Fixing them so I don't cause later merge pain is difficult. I'm
therefore going to commit this series (staggered as previously
requested) without documentation and then commit a consolidated
documentation patch for them.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#89Greg Stark
stark@mit.edu
In reply to: Andrew Dunstan (#88)
Re: SQL/JSON: JSON_TABLE

FYI I think the patch failure in the cfbot is spurious because the
cfbot got confused by Erik's patch.

#90Andrew Dunstan
andrew@dunslane.net
In reply to: Greg Stark (#89)
Re: SQL/JSON: JSON_TABLE

On 3/28/22 15:48, Greg Stark wrote:

FYI I think the patch failure in the cfbot is spurious because the
cfbot got confused by Erik's patch.

The cfbot is likely to be confused until I am finished committing the
SQL/JSON patches. Just disregard it.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#91Andres Freund
andres@anarazel.de
In reply to: Andrew Dunstan (#88)
Re: SQL/JSON: JSON_TABLE

Hi,

On 2022-03-27 16:53:57 -0400, Andrew Dunstan wrote:

I'm therefore going to commit this series

The new jsonb_sqljson test is, on my machine, the slowest test in the main
regression tests:

4639 ms jsonb_sqljson
2401 ms btree_index
2166 ms stats_ext
2027 ms alter_table
1616 ms triggers
1498 ms brin
1489 ms join_hash
1367 ms foreign_key
1345 ms tuplesort
1202 ms plpgsql

Any chance the slowness isn't required slowness?

Greetings,

Andres Freund

#92Tom Lane
tgl@sss.pgh.pa.us
In reply to: Andres Freund (#91)
Re: SQL/JSON: JSON_TABLE

Andres Freund <andres@anarazel.de> writes:

The new jsonb_sqljson test is, on my machine, the slowest test in the main
regression tests:
...
Any chance the slowness isn't required slowness?

In general, there's been a serious bump in the buildfarm cycle
time in the last month --- for example, on my admittedly slow
animal prairiedog, the cycle time excluding the "make" phase
(which is really variable because ccache) has gone from about
4:26 a month ago to 5:25 in its last run.

I don't want to worry about this before feature freeze, but after that
we should take a hard look at cutting out unnecessary test cycles.

regards, tom lane

#93Andrew Dunstan
andrew@dunslane.net
In reply to: Andres Freund (#91)
Re: SQL/JSON: JSON_TABLE

On 4/5/22 22:21, Andres Freund wrote:

Hi,

On 2022-03-27 16:53:57 -0400, Andrew Dunstan wrote:

I'm therefore going to commit this series

The new jsonb_sqljson test is, on my machine, the slowest test in the main
regression tests:

4639 ms jsonb_sqljson
2401 ms btree_index
2166 ms stats_ext
2027 ms alter_table
1616 ms triggers
1498 ms brin
1489 ms join_hash
1367 ms foreign_key
1345 ms tuplesort
1202 ms plpgsql

Any chance the slowness isn't required slowness?

I'll take a look.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#94Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#93)
Re: SQL/JSON: JSON_TABLE

On 4/6/22 09:20, Andrew Dunstan wrote:

On 4/5/22 22:21, Andres Freund wrote:

Hi,

On 2022-03-27 16:53:57 -0400, Andrew Dunstan wrote:

I'm therefore going to commit this series

The new jsonb_sqljson test is, on my machine, the slowest test in the main
regression tests:

4639 ms jsonb_sqljson
2401 ms btree_index
2166 ms stats_ext
2027 ms alter_table
1616 ms triggers
1498 ms brin
1489 ms join_hash
1367 ms foreign_key
1345 ms tuplesort
1202 ms plpgsql

Any chance the slowness isn't required slowness?

I'll take a look.

I've committed a change that should reduce it substantially, but there
might be more work to do.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#95Stephen Frost
sfrost@snowman.net
In reply to: Andrew Dunstan (#94)
Re: SQL/JSON: JSON_TABLE

Greetings,

* Andrew Dunstan (andrew@dunslane.net) wrote:

On 4/6/22 09:20, Andrew Dunstan wrote:

On 4/5/22 22:21, Andres Freund wrote:

On 2022-03-27 16:53:57 -0400, Andrew Dunstan wrote:

I'm therefore going to commit this series

The new jsonb_sqljson test is, on my machine, the slowest test in the main
regression tests:

4639 ms jsonb_sqljson
2401 ms btree_index
2166 ms stats_ext
2027 ms alter_table
1616 ms triggers
1498 ms brin
1489 ms join_hash
1367 ms foreign_key
1345 ms tuplesort
1202 ms plpgsql

Any chance the slowness isn't required slowness?

I'll take a look.

I've committed a change that should reduce it substantially, but there
might be more work to do.

All for improving the speed, but this broke the recovery tests (as
noticed by the buildfarm). Maybe we should add
--no-unlogged-table-data to those pg_dumpall runs?

Thanks,

Stephen

#96Andrew Dunstan
andrew@dunslane.net
In reply to: Stephen Frost (#95)
Re: SQL/JSON: JSON_TABLE

On 4/6/22 11:11, Stephen Frost wrote:

Greetings,

* Andrew Dunstan (andrew@dunslane.net) wrote:

On 4/6/22 09:20, Andrew Dunstan wrote:

On 4/5/22 22:21, Andres Freund wrote:

On 2022-03-27 16:53:57 -0400, Andrew Dunstan wrote:

I'm therefore going to commit this series

The new jsonb_sqljson test is, on my machine, the slowest test in the main
regression tests:

4639 ms jsonb_sqljson
2401 ms btree_index
2166 ms stats_ext
2027 ms alter_table
1616 ms triggers
1498 ms brin
1489 ms join_hash
1367 ms foreign_key
1345 ms tuplesort
1202 ms plpgsql

Any chance the slowness isn't required slowness?

I'll take a look.

I've committed a change that should reduce it substantially, but there
might be more work to do.

All for improving the speed, but this broke the recovery tests (as
noticed by the buildfarm). Maybe we should add
--no-unlogged-table-data to those pg_dumpall runs?

I think we should, but I think here the obvious solution is to drop the
table when we're done with it. I'll test that.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#97Andrew Dunstan
andrew@dunslane.net
In reply to: Andrew Dunstan (#96)
Re: SQL/JSON: JSON_TABLE

On 4/6/22 11:33, Andrew Dunstan wrote:

On 4/6/22 11:11, Stephen Frost wrote:

Greetings,

* Andrew Dunstan (andrew@dunslane.net) wrote:

On 4/6/22 09:20, Andrew Dunstan wrote:

On 4/5/22 22:21, Andres Freund wrote:

On 2022-03-27 16:53:57 -0400, Andrew Dunstan wrote:

I'm therefore going to commit this series

The new jsonb_sqljson test is, on my machine, the slowest test in the main
regression tests:

4639 ms jsonb_sqljson
2401 ms btree_index
2166 ms stats_ext
2027 ms alter_table
1616 ms triggers
1498 ms brin
1489 ms join_hash
1367 ms foreign_key
1345 ms tuplesort
1202 ms plpgsql

Any chance the slowness isn't required slowness?

I'll take a look.

I've committed a change that should reduce it substantially, but there
might be more work to do.

All for improving the speed, but this broke the recovery tests (as
noticed by the buildfarm). Maybe we should add
--no-unlogged-table-data to those pg_dumpall runs?

I think we should, but I think here the obvious solution is to drop the
table when we're done with it. I'll test that.

It does work, but Tom prefers not to have the test at all, so I'll just
rip it out.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#98Tom Lane
tgl@sss.pgh.pa.us
In reply to: Andrew Dunstan (#97)
Re: SQL/JSON: JSON_TABLE

Andrew Dunstan <andrew@dunslane.net> writes:

I think we should, but I think here the obvious solution is to drop the
table when we're done with it. I'll test that.

It does work, but Tom prefers not to have the test at all, so I'll just
rip it out.

Perhaps moving it to some other place (test/modules/something?) would
be appropriate. But I don't think that the core regression tests,
which are currently run four or more times per buildfarm cycle,
are an appropriate place for million-row test cases.

regards, tom lane

#99Andres Freund
andres@anarazel.de
In reply to: Andrew Dunstan (#97)
Re: SQL/JSON: JSON_TABLE

Hi,

On 2022-04-06 11:50:11 -0400, Andrew Dunstan wrote:

It does work, but Tom prefers not to have the test at all, so I'll just
rip it out.

If I understand correctly the reason a large table is needed is to test
parallelism, right? Wouldn't the better fix be to just tweak the parallelism
settings for that table? See select_parallel.sql:

-- encourage use of parallel plans
set parallel_setup_cost=0;
set parallel_tuple_cost=0;
set min_parallel_table_scan_size=0;
set max_parallel_workers_per_gather=4;

might be worth also setting
set parallel_leader_participation = off;

to avoid the leader processing everything before workers have even started up.

Greetings,

Andres Freund

#100Andrew Dunstan
andrew@dunslane.net
In reply to: Andres Freund (#99)
Re: SQL/JSON: JSON_TABLE

On 4/6/22 12:59, Andres Freund wrote:

Hi,

On 2022-04-06 11:50:11 -0400, Andrew Dunstan wrote:

It does work, but Tom prefers not to have the test at all, so I'll just
rip it out.

If I understand correctly the reason a large table is needed is to test
parallelism, right? Wouldn't the better fix be to just tweak the parallelism
settings for that table? See select_parallel.sql:

-- encourage use of parallel plans
set parallel_setup_cost=0;
set parallel_tuple_cost=0;
set min_parallel_table_scan_size=0;
set max_parallel_workers_per_gather=4;

might be worth also setting
set parallel_leader_participation = off;

to avoid the leader processing everything before workers have even started up.

OK, done that way, thanks. I also kept the table as unlogged and dropped
it at the end.

cheers

andrew

--
Andrew Dunstan
EDB: https://www.enterprisedb.com

#101Andres Freund
andres@anarazel.de
In reply to: Stephen Frost (#95)
Re: SQL/JSON: JSON_TABLE

Hi,

On 2022-04-06 11:11:42 -0400, Stephen Frost wrote:

Maybe we should add --no-unlogged-table-data to those pg_dumpall runs?

Yes, I think we should. And then we should explicitly add an unlogged table
that isn't dropped. That way we get pg_upgrade testing etc.

Thomas, what do you think?

Greetings,

Andres Freund